Split SqlTiddlerStore into SqlTiddlerStore and SqlTiddlerDatabase

The motivation is to encapsulate knowledge of the SQL queries
This commit is contained in:
Jeremy Ruston 2024-01-22 22:08:55 +00:00
parent dc8692044c
commit da5b316358
5 changed files with 521 additions and 408 deletions

View File

@ -41,7 +41,6 @@ exports.startup = function() {
$tw.sqlTiddlerStore = new SqlTiddlerStore({
databasePath: databasePath
});
$tw.sqlTiddlerStore.createTables();
$tw.sqlTiddlerStore.updateAdminWiki();
// Create bags and recipes
$tw.sqlTiddlerStore.createBag("bag-alpha");

View File

@ -0,0 +1,412 @@
/*\
title: $:/plugins/tiddlywiki/multiwikiserver/sql-tiddler-database.js
type: application/javascript
module-type: library
Low level SQL functions to store and retrieve tiddlers in a SQLite database.
This class is intended to encapsulate all the SQL queries used to access the database.
\*/
(function() {
/*
Create a tiddler store. Options include:
databasePath - path to the database file (can be ":memory:" to get a temporary database)
*/
function SqlTiddlerDatabase(options) {
options = options || {};
// Create the database
var databasePath = options.databasePath || ":memory:";
this.db = new $tw.sqlite3.Database(databasePath,{verbose: undefined && console.log});
}
SqlTiddlerDatabase.prototype.close = function() {
this.db.close();
this.db = undefined;
};
SqlTiddlerDatabase.prototype.runStatement = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.run(params);
};
SqlTiddlerDatabase.prototype.runStatementGet = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.get(params);
};
SqlTiddlerDatabase.prototype.runStatementGetAll = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.all(params);
};
SqlTiddlerDatabase.prototype.runStatements = function(sqlArray) {
for(const sql of sqlArray) {
this.runStatement(sql);
}
};
SqlTiddlerDatabase.prototype.createTables = function() {
this.runStatements([`
-- Bags have names and access control settings
CREATE TABLE IF NOT EXISTS bags (
bag_id INTEGER PRIMARY KEY AUTOINCREMENT,
bag_name TEXT UNIQUE,
accesscontrol TEXT
)
`,`
-- Recipes have names...
CREATE TABLE IF NOT EXISTS recipes (
recipe_id INTEGER PRIMARY KEY AUTOINCREMENT,
recipe_name TEXT UNIQUE
)
`,`
-- ...and recipes also have an ordered list of bags
CREATE TABLE IF NOT EXISTS recipe_bags (
recipe_id INTEGER,
bag_id INTEGER,
position INTEGER,
FOREIGN KEY (recipe_id) REFERENCES recipes(recipe_id) ON UPDATE CASCADE ON DELETE CASCADE,
FOREIGN KEY (bag_id) REFERENCES bags(bag_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (recipe_id, bag_id)
)
`,`
-- Tiddlers are contained in bags and have titles
CREATE TABLE IF NOT EXISTS tiddlers (
tiddler_id INTEGER PRIMARY KEY AUTOINCREMENT,
bag_id INTEGER,
title TEXT,
FOREIGN KEY (bag_id) REFERENCES bags(bag_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (bag_id, title)
)
`,`
-- Tiddlers also have unordered lists of fields, each of which has a name and associated value
CREATE TABLE IF NOT EXISTS fields (
tiddler_id INTEGER,
field_name TEXT,
field_value TEXT,
FOREIGN KEY (tiddler_id) REFERENCES tiddlers(tiddler_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (tiddler_id, field_name)
)
`]);
};
SqlTiddlerDatabase.prototype.logTables = function() {
var self = this;
function sqlLogTable(table) {
console.log(`TABLE ${table}:`);
let statement = self.db.prepare(`select * from ${table}`);
for(const row of statement.all()) {
console.log(row);
}
}
const tables = ["recipes","bags","recipe_bags","tiddlers","fields"];
for(const table of tables) {
sqlLogTable(table);
}
};
SqlTiddlerDatabase.prototype.listBags = function() {
const rows = this.runStatementGetAll(`
SELECT bag_name, accesscontrol
FROM bags
ORDER BY bag_name
`);
return rows;
};
SqlTiddlerDatabase.prototype.createBag = function(bagname) {
// Run the queries
this.runStatement(`
INSERT OR IGNORE INTO bags (bag_name, accesscontrol)
VALUES ($bag_name, '')
`,{
bag_name: bagname
});
this.runStatement(`
UPDATE bags
SET accesscontrol = $accesscontrol
WHERE bag_name = $bag_name
`,{
bag_name: bagname,
accesscontrol: "[some access control stuff]"
});
};
SqlTiddlerDatabase.prototype.listRecipes = function() {
const rows = this.runStatementGetAll(`
SELECT recipe_name
FROM recipes
ORDER BY recipe_name
`);
return rows;
};
SqlTiddlerDatabase.prototype.createRecipe = function(recipename,bagnames) {
// Run the queries
this.runStatement(`
-- Create the entry in the recipes table if required
INSERT OR IGNORE INTO recipes (recipe_name)
VALUES ($recipe_name)
`,{
recipe_name: recipename
});
this.runStatement(`
-- Delete existing recipe_bags entries for this recipe
DELETE FROM recipe_bags WHERE recipe_id = (SELECT recipe_id FROM recipes WHERE recipe_name = $recipe_name)
`,{
recipe_name: recipename
});
this.runStatement(`
INSERT INTO recipe_bags (recipe_id, bag_id, position)
SELECT r.recipe_id, b.bag_id, j.key as position
FROM recipes r
JOIN bags b
INNER JOIN json_each($bag_names) AS j ON j.value = b.bag_name
WHERE r.recipe_name = $recipe_name
`,{
recipe_name: recipename,
bag_names: JSON.stringify(bagnames)
});
};
/*
Returns {tiddler_id:}
*/
SqlTiddlerDatabase.prototype.saveBagTiddler = function(tiddlerFields,bagname) {
// Update the tiddlers table
var info = this.runStatement(`
INSERT OR REPLACE INTO tiddlers (bag_id, title)
VALUES (
(SELECT bag_id FROM bags WHERE bag_name = $bag_name),
$title
)
`,{
title: tiddlerFields.title,
bag_name: bagname
});
// Update the fields table
this.runStatement(`
INSERT OR REPLACE INTO fields (tiddler_id, field_name, field_value)
SELECT
t.tiddler_id,
json_each.key AS field_name,
json_each.value AS field_value
FROM (
SELECT tiddler_id
FROM tiddlers
WHERE bag_id = (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
) AND title = $title
) AS t
JOIN json_each($field_values) AS json_each
`,{
title: tiddlerFields.title,
bag_name: bagname,
field_values: JSON.stringify(Object.assign({},tiddlerFields,{title: undefined}))
});
return {
tiddler_id: info.lastInsertRowid
}
};
/*
Returns {tiddler_id:,bag_name:}
*/
SqlTiddlerDatabase.prototype.saveRecipeTiddler = function(tiddlerFields,recipename) {
// Find the topmost bag in the recipe
var row = this.runStatementGet(`
SELECT b.bag_name
FROM bags AS b
JOIN (
SELECT rb.bag_id
FROM recipe_bags AS rb
WHERE rb.recipe_id = (
SELECT recipe_id
FROM recipes
WHERE recipe_name = $recipe_name
)
ORDER BY rb.position DESC
LIMIT 1
) AS selected_bag
ON b.bag_id = selected_bag.bag_id
`,{
recipe_name: recipename
});
// Save the tiddler to the topmost bag
var info = this.saveBagTiddler(tiddlerFields,row.bag_name);
return {
tiddler_id: info.tiddler_id,
bag_name: row.bag_name
};
};
SqlTiddlerDatabase.prototype.deleteTiddler = function(title,bagname) {
// Run the queries
this.runStatement(`
DELETE FROM fields
WHERE tiddler_id IN (
SELECT t.tiddler_id
FROM tiddlers AS t
INNER JOIN bags AS b ON t.bag_id = b.bag_id
WHERE b.bag_name = $bag_name AND t.title = $title
)
`,{
title: title,
bag_name: bagname
});
this.runStatement(`
DELETE FROM tiddlers
WHERE bag_id = (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
) AND title = $title
`,{
title: title,
bag_name: bagname
});
};
/*
returns {tiddler_id:,tiddler:}
*/
SqlTiddlerDatabase.prototype.getBagTiddler = function(title,bagname) {
const rows = this.runStatementGetAll(`
SELECT field_name, field_value, tiddler_id
FROM fields
WHERE tiddler_id = (
SELECT t.tiddler_id
FROM bags AS b
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE t.title = $title AND b.bag_name = $bag_name
)
`,{
title: title,
bag_name: bagname
});
if(rows.length === 0) {
return null;
} else {
return {
tiddler_id: rows[0].tiddler_id,
tiddler: rows.reduce((accumulator,value) => {
accumulator[value["field_name"]] = value.field_value;
return accumulator;
},{title: title})
};
}
};
/*
Returns {bag_name:, tiddler: {fields}, tiddler_id:}
*/
SqlTiddlerDatabase.prototype.getRecipeTiddler = function(title,recipename) {
const rowTiddlerId = this.runStatementGet(`
SELECT t.tiddler_id, b.bag_name
FROM bags AS b
INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id
INNER JOIN recipes AS r ON rb.recipe_id = r.recipe_id
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE r.recipe_name = $recipe_name
AND t.title = $title
ORDER BY rb.position DESC
LIMIT 1
`,{
title: title,
recipe_name: recipename
});
if(!rowTiddlerId) {
return null;
}
// Get the fields
const rows = this.runStatementGetAll(`
SELECT field_name, field_value
FROM fields
WHERE tiddler_id = $tiddler_id
`,{
tiddler_id: rowTiddlerId.tiddler_id,
recipe_name: recipename
});
return {
bag_name: rowTiddlerId.bag_name,
tiddler_id: rowTiddlerId.tiddler_id,
tiddler: rows.reduce((accumulator,value) => {
accumulator[value["field_name"]] = value.field_value;
return accumulator;
},{title: title})
};
};
/*
Get the titles of the tiddlers in a bag. Returns an empty array for bags that do not exist
*/
SqlTiddlerDatabase.prototype.getBagTiddlers = function(bagname) {
const rows = this.runStatementGetAll(`
SELECT DISTINCT title
FROM tiddlers
WHERE bag_id IN (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
)
ORDER BY title ASC
`,{
bag_name: bagname
});
return rows.map(value => value.title);
};
/*
Get the titles of the tiddlers in a recipe as {title:,bag_name:}. Returns an empty array for recipes that do not exist
*/
SqlTiddlerDatabase.prototype.getRecipeTiddlers = function(recipename) {
const rows = this.runStatementGetAll(`
SELECT title, bag_name
FROM (
SELECT t.title, b.bag_name, MAX(rb.position) AS position
FROM bags AS b
INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id
INNER JOIN recipes AS r ON rb.recipe_id = r.recipe_id
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE r.recipe_name = $recipe_name
GROUP BY t.title
ORDER BY t.title
)
`,{
recipe_name: recipename
});
return rows;
};
/*
Get the names of the bags in a recipe. Returns an empty array for recipes that do not exist
*/
SqlTiddlerDatabase.prototype.getRecipeBags = function(recipename) {
const rows = this.runStatementGetAll(`
SELECT bags.bag_name
FROM bags
JOIN (
SELECT rb.bag_id
FROM recipe_bags AS rb
JOIN recipes AS r ON rb.recipe_id = r.recipe_id
WHERE r.recipe_name = $recipe_name
ORDER BY rb.position
) AS bag_priority ON bags.bag_id = bag_priority.bag_id
`,{
recipe_name: recipename
});
return rows.map(value => value.bag_name);
};
exports.SqlTiddlerDatabase = SqlTiddlerDatabase;
})();

View File

@ -3,7 +3,11 @@ title: $:/plugins/tiddlywiki/multiwikiserver/sql-tiddler-store.js
type: application/javascript
module-type: library
Functions to perform basic tiddler operations with a sqlite3 database
Higher level functions to perform basic tiddler operations with a sqlite3 database.
This class is largely a wrapper for the sql-tiddler-database.js class, adding the following functionality:
* Synchronising bag and recipe names to the admin wiki
\*/
@ -20,37 +24,17 @@ function SqlTiddlerStore(options) {
this.adminWiki = options.adminWiki || $tw.wiki;
this.entityStateTiddlerPrefix = "$:/state/multiwikiserver/";
// Create the database
var databasePath = options.databasePath || ":memory:";
this.db = new $tw.sqlite3.Database(databasePath,{verbose: undefined && console.log});
this.databasePath = options.databasePath || ":memory:";
var SqlTiddlerDatabase = require("$:/plugins/tiddlywiki/multiwikiserver/sql-tiddler-database.js").SqlTiddlerDatabase;
this.sqlTiddlerDatabase = new SqlTiddlerDatabase({
databasePath: this.databasePath
});
this.sqlTiddlerDatabase.createTables();
}
SqlTiddlerStore.prototype.close = function() {
this.db.close();
this.db = undefined;
};
SqlTiddlerStore.prototype.runStatement = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.run(params);
};
SqlTiddlerStore.prototype.runStatementGet = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.get(params);
};
SqlTiddlerStore.prototype.runStatementGetAll = function(sql,params) {
params = params || {};
const statement = this.db.prepare(sql);
return statement.all(params);
};
SqlTiddlerStore.prototype.runStatements = function(sqlArray) {
for(const sql of sqlArray) {
this.runStatement(sql);
}
this.sqlTiddlerDatabase.close();
this.sqlTiddlerDatabase = undefined;
};
SqlTiddlerStore.prototype.saveEntityStateTiddler = function(tiddler) {
@ -77,91 +61,16 @@ SqlTiddlerStore.prototype.updateAdminWiki = function() {
}
};
SqlTiddlerStore.prototype.createTables = function() {
this.runStatements([`
-- Bags have names and access control settings
CREATE TABLE IF NOT EXISTS bags (
bag_id INTEGER PRIMARY KEY AUTOINCREMENT,
bag_name TEXT UNIQUE,
accesscontrol TEXT
)
`,`
-- Recipes have names...
CREATE TABLE IF NOT EXISTS recipes (
recipe_id INTEGER PRIMARY KEY AUTOINCREMENT,
recipe_name TEXT UNIQUE
)
`,`
-- ...and recipes also have an ordered list of bags
CREATE TABLE IF NOT EXISTS recipe_bags (
recipe_id INTEGER,
bag_id INTEGER,
position INTEGER,
FOREIGN KEY (recipe_id) REFERENCES recipes(recipe_id) ON UPDATE CASCADE ON DELETE CASCADE,
FOREIGN KEY (bag_id) REFERENCES bags(bag_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (recipe_id, bag_id)
)
`,`
-- Tiddlers are contained in bags and have titles
CREATE TABLE IF NOT EXISTS tiddlers (
tiddler_id INTEGER PRIMARY KEY AUTOINCREMENT,
bag_id INTEGER,
title TEXT,
FOREIGN KEY (bag_id) REFERENCES bags(bag_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (bag_id, title)
)
`,`
-- Tiddlers also have unordered lists of fields, each of which has a name and associated value
CREATE TABLE IF NOT EXISTS fields (
tiddler_id INTEGER,
field_name TEXT,
field_value TEXT,
FOREIGN KEY (tiddler_id) REFERENCES tiddlers(tiddler_id) ON UPDATE CASCADE ON DELETE CASCADE,
UNIQUE (tiddler_id, field_name)
)
`]);
};
SqlTiddlerStore.prototype.logTables = function() {
var self = this;
function sqlLogTable(table) {
console.log(`TABLE ${table}:`);
let statement = self.db.prepare(`select * from ${table}`);
for(const row of statement.all()) {
console.log(row);
}
}
const tables = ["recipes","bags","recipe_bags","tiddlers","fields"];
for(const table of tables) {
sqlLogTable(table);
}
this.sqlTiddlerDatabase.logTables();
};
SqlTiddlerStore.prototype.listBags = function() {
const rows = this.runStatementGetAll(`
SELECT bag_name, accesscontrol
FROM bags
ORDER BY bag_name
`);
return rows;
return this.sqlTiddlerDatabase.listBags();
};
SqlTiddlerStore.prototype.createBag = function(bagname) {
// Run the queries
this.runStatement(`
INSERT OR IGNORE INTO bags (bag_name, accesscontrol)
VALUES ($bag_name, '')
`,{
bag_name: bagname
});
this.runStatement(`
UPDATE bags
SET accesscontrol = $accesscontrol
WHERE bag_name = $bag_name
`,{
bag_name: bagname,
accesscontrol: "[some access control stuff]"
});
this.sqlTiddlerDatabase.createBag(bagname);
this.saveEntityStateTiddler({
title: "bags/" + bagname,
"bag-name": bagname,
@ -170,40 +79,11 @@ SqlTiddlerStore.prototype.createBag = function(bagname) {
};
SqlTiddlerStore.prototype.listRecipes = function() {
const rows = this.runStatementGetAll(`
SELECT recipe_name
FROM recipes
ORDER BY recipe_name
`);
return rows;
return this.sqlTiddlerDatabase.listRecipes();
};
SqlTiddlerStore.prototype.createRecipe = function(recipename,bagnames) {
// Run the queries
this.runStatement(`
-- Create the entry in the recipes table if required
INSERT OR IGNORE INTO recipes (recipe_name)
VALUES ($recipe_name)
`,{
recipe_name: recipename
});
this.runStatement(`
-- Delete existing recipe_bags entries for this recipe
DELETE FROM recipe_bags WHERE recipe_id = (SELECT recipe_id FROM recipes WHERE recipe_name = $recipe_name)
`,{
recipe_name: recipename
});
this.runStatement(`
INSERT INTO recipe_bags (recipe_id, bag_id, position)
SELECT r.recipe_id, b.bag_id, j.key as position
FROM recipes r
JOIN bags b
INNER JOIN json_each($bag_names) AS j ON j.value = b.bag_name
WHERE r.recipe_name = $recipe_name
`,{
recipe_name: recipename,
bag_names: JSON.stringify(bagnames)
});
this.sqlTiddlerDatabase.createRecipe(recipename,bagnames);
this.saveEntityStateTiddler({
title: "recipes/" + recipename,
"recipe-name": recipename,
@ -216,231 +96,53 @@ SqlTiddlerStore.prototype.createRecipe = function(recipename,bagnames) {
Returns {tiddler_id:}
*/
SqlTiddlerStore.prototype.saveBagTiddler = function(tiddlerFields,bagname) {
// Update the tiddlers table
var info = this.runStatement(`
INSERT OR REPLACE INTO tiddlers (bag_id, title)
VALUES (
(SELECT bag_id FROM bags WHERE bag_name = $bag_name),
$title
)
`,{
title: tiddlerFields.title,
bag_name: bagname
});
// Update the fields table
this.runStatement(`
INSERT OR REPLACE INTO fields (tiddler_id, field_name, field_value)
SELECT
t.tiddler_id,
json_each.key AS field_name,
json_each.value AS field_value
FROM (
SELECT tiddler_id
FROM tiddlers
WHERE bag_id = (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
) AND title = $title
) AS t
JOIN json_each($field_values) AS json_each
`,{
title: tiddlerFields.title,
bag_name: bagname,
field_values: JSON.stringify(Object.assign({},tiddlerFields,{title: undefined}))
});
return {
tiddler_id: info.lastInsertRowid
}
return this.sqlTiddlerDatabase.saveBagTiddler(tiddlerFields,bagname);
};
/*
Returns {tiddler_id:,bag_name:}
*/
SqlTiddlerStore.prototype.saveRecipeTiddler = function(tiddlerFields,recipename) {
// Find the topmost bag in the recipe
var row = this.runStatementGet(`
SELECT b.bag_name
FROM bags AS b
JOIN (
SELECT rb.bag_id
FROM recipe_bags AS rb
WHERE rb.recipe_id = (
SELECT recipe_id
FROM recipes
WHERE recipe_name = $recipe_name
)
ORDER BY rb.position DESC
LIMIT 1
) AS selected_bag
ON b.bag_id = selected_bag.bag_id
`,{
recipe_name: recipename
});
// Save the tiddler to the topmost bag
var info = this.saveBagTiddler(tiddlerFields,row.bag_name);
return {
tiddler_id: info.tiddler_id,
bag_name: row.bag_name
};
return this.sqlTiddlerDatabase.saveRecipeTiddler(tiddlerFields,recipename);
};
SqlTiddlerStore.prototype.deleteTiddler = function(title,bagname) {
// Run the queries
this.runStatement(`
DELETE FROM fields
WHERE tiddler_id IN (
SELECT t.tiddler_id
FROM tiddlers AS t
INNER JOIN bags AS b ON t.bag_id = b.bag_id
WHERE b.bag_name = $bag_name AND t.title = $title
)
`,{
title: title,
bag_name: bagname
});
this.runStatement(`
DELETE FROM tiddlers
WHERE bag_id = (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
) AND title = $title
`,{
title: title,
bag_name: bagname
});
this.sqlTiddlerDatabase.deleteTiddler(title,bagname);
};
/*
returns {tiddler_id:,tiddler:}
*/
SqlTiddlerStore.prototype.getBagTiddler = function(title,bagname) {
const rows = this.runStatementGetAll(`
SELECT field_name, field_value, tiddler_id
FROM fields
WHERE tiddler_id = (
SELECT t.tiddler_id
FROM bags AS b
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE t.title = $title AND b.bag_name = $bag_name
)
`,{
title: title,
bag_name: bagname
});
if(rows.length === 0) {
return null;
} else {
return {
tiddler_id: rows[0].tiddler_id,
tiddler: rows.reduce((accumulator,value) => {
accumulator[value["field_name"]] = value.field_value;
return accumulator;
},{title: title})
};
}
return this.sqlTiddlerDatabase.getBagTiddler(title,bagname);
};
/*
Returns {bag_name:, tiddler: {fields}, tiddler_id:}
*/
SqlTiddlerStore.prototype.getRecipeTiddler = function(title,recipename) {
const rowTiddlerId = this.runStatementGet(`
SELECT t.tiddler_id, b.bag_name
FROM bags AS b
INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id
INNER JOIN recipes AS r ON rb.recipe_id = r.recipe_id
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE r.recipe_name = $recipe_name
AND t.title = $title
ORDER BY rb.position DESC
LIMIT 1
`,{
title: title,
recipe_name: recipename
});
if(!rowTiddlerId) {
return null;
}
// Get the fields
const rows = this.runStatementGetAll(`
SELECT field_name, field_value
FROM fields
WHERE tiddler_id = $tiddler_id
`,{
tiddler_id: rowTiddlerId.tiddler_id,
recipe_name: recipename
});
return {
bag_name: rowTiddlerId.bag_name,
tiddler_id: rowTiddlerId.tiddler_id,
tiddler: rows.reduce((accumulator,value) => {
accumulator[value["field_name"]] = value.field_value;
return accumulator;
},{title: title})
};
return this.sqlTiddlerDatabase.getRecipeTiddler(title,recipename);
};
/*
Get the titles of the tiddlers in a bag. Returns an empty array for bags that do not exist
*/
SqlTiddlerStore.prototype.getBagTiddlers = function(bagname) {
const rows = this.runStatementGetAll(`
SELECT DISTINCT title
FROM tiddlers
WHERE bag_id IN (
SELECT bag_id
FROM bags
WHERE bag_name = $bag_name
)
ORDER BY title ASC
`,{
bag_name: bagname
});
return rows.map(value => value.title);
return this.sqlTiddlerDatabase.getBagTiddlers(bagname);
};
/*
Get the titles of the tiddlers in a recipe. Returns an empty array for recipes that do not exist
Get the titles of the tiddlers in a recipe as {title:,bag_name:}. Returns an empty array for recipes that do not exist
*/
SqlTiddlerStore.prototype.getRecipeTiddlers = function(recipename) {
const rows = this.runStatementGetAll(`
SELECT title, bag_name
FROM (
SELECT t.title, b.bag_name, MAX(rb.position) AS position
FROM bags AS b
INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id
INNER JOIN recipes AS r ON rb.recipe_id = r.recipe_id
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
WHERE r.recipe_name = $recipe_name
GROUP BY t.title
ORDER BY t.title
)
`,{
recipe_name: recipename
});
return rows;
return this.sqlTiddlerDatabase.getRecipeTiddlers(recipename);
};
/*
Get the names of the bags in a recipe. Returns an empty array for recipes that do not exist
*/
SqlTiddlerStore.prototype.getRecipeBags = function(recipename) {
const rows = this.runStatementGetAll(`
SELECT bags.bag_name
FROM bags
JOIN (
SELECT rb.bag_id
FROM recipe_bags AS rb
JOIN recipes AS r ON rb.recipe_id = r.recipe_id
WHERE r.recipe_name = $recipe_name
ORDER BY rb.position
) AS bag_priority ON bags.bag_id = bag_priority.bag_id
`,{
recipe_name: recipename
});
return rows.map(value => value.bag_name);
return this.sqlTiddlerDatabase.getRecipeBags(recipename);
};
exports.SqlTiddlerStore = SqlTiddlerStore;

View File

@ -0,0 +1,82 @@
/*\
title: tests-sql-tiddler-database.js
type: application/javascript
tags: [[$:/tags/test-spec]]
Tests the SQL tiddler database layer
\*/
(function(){
/*jslint node: true, browser: true */
/*global $tw: false */
"use strict";
if($tw.node) {
describe("SQL tiddler store", function() {
// Create and initialise the tiddler store
var SqlTiddlerDatabase = require("$:/plugins/tiddlywiki/multiwikiserver/sql-tiddler-database.js").SqlTiddlerDatabase;
const sqlTiddlerDatabase = new SqlTiddlerDatabase({
adminWiki: new $tw.Wiki()
});
sqlTiddlerDatabase.createTables();
// Create bags and recipes
sqlTiddlerDatabase.createBag("bag-alpha");
sqlTiddlerDatabase.createBag("bag-beta");
sqlTiddlerDatabase.createBag("bag-gamma");
sqlTiddlerDatabase.createRecipe("recipe-rho",["bag-alpha","bag-beta"]);
sqlTiddlerDatabase.createRecipe("recipe-sigma",["bag-alpha","bag-gamma"]);
sqlTiddlerDatabase.createRecipe("recipe-tau",["bag-alpha"]);
sqlTiddlerDatabase.createRecipe("recipe-upsilon",["bag-alpha","bag-gamma","bag-beta"]);
// Tear down
afterAll(function() {
// Close the database
sqlTiddlerDatabase.close();
});
// Run tests
it("should save and retrieve tiddlers", function() {
// Save tiddlers
sqlTiddlerDatabase.saveBagTiddler({title: "Another Tiddler",text: "I'm in alpha",tags: "one two three"},"bag-alpha");
sqlTiddlerDatabase.saveBagTiddler({title: "Hello There",text: "I'm in alpha as well",tags: "one two three"},"bag-alpha");
sqlTiddlerDatabase.saveBagTiddler({title: "Hello There",text: "I'm in beta",tags: "four five six"},"bag-beta");
sqlTiddlerDatabase.saveBagTiddler({title: "Hello There",text: "I'm in gamma",tags: "seven eight nine"},"bag-gamma");
// Verify what we've got
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-rho")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-beta' }
]);
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-sigma")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-gamma' }
]);
expect(sqlTiddlerDatabase.getRecipeTiddler("Hello There","recipe-rho").tiddler).toEqual({ title: "Hello There", text: "I'm in beta", tags: "four five six" });
expect(sqlTiddlerDatabase.getRecipeTiddler("Missing Tiddler","recipe-rho")).toEqual(null);
expect(sqlTiddlerDatabase.getRecipeTiddler("Another Tiddler","recipe-rho").tiddler).toEqual({ title: "Another Tiddler", text: "I'm in alpha", tags: "one two three" });
expect(sqlTiddlerDatabase.getRecipeTiddler("Hello There","recipe-sigma").tiddler).toEqual({ title: "Hello There", text: "I'm in gamma", tags: "seven eight nine" });
expect(sqlTiddlerDatabase.getRecipeTiddler("Another Tiddler","recipe-sigma").tiddler).toEqual({ title: "Another Tiddler", text: "I'm in alpha", tags: "one two three" });
expect(sqlTiddlerDatabase.getRecipeTiddler("Hello There","recipe-upsilon").tiddler).toEqual({title: "Hello There",text: "I'm in beta",tags: "four five six"});
// Delete a tiddlers to ensure the underlying tiddler in the recipe shows through
sqlTiddlerDatabase.deleteTiddler("Hello There","bag-beta");
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-rho")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-alpha' }
]);
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-sigma")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-gamma' }
]);
expect(sqlTiddlerDatabase.getRecipeTiddler("Hello There","recipe-beta")).toEqual(null);
sqlTiddlerDatabase.deleteTiddler("Another Tiddler","bag-alpha");
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-rho")).toEqual([ { title: 'Hello There', bag_name: 'bag-alpha' } ]);
expect(sqlTiddlerDatabase.getRecipeTiddlers("recipe-sigma")).toEqual([ { title: 'Hello There', bag_name: 'bag-gamma' } ]);
// Save a recipe tiddler
expect(sqlTiddlerDatabase.saveRecipeTiddler({title: "More", text: "None"},"recipe-rho")).toEqual({tiddler_id: 5, bag_name: 'bag-beta'});
expect(sqlTiddlerDatabase.getRecipeTiddler("More","recipe-rho").tiddler).toEqual({title: "More", text: "None"});
});
});
}
})();

View File

@ -1,82 +0,0 @@
/*\
title: tests-sql-tiddler-store.js
type: application/javascript
tags: [[$:/tags/test-spec]]
Tests the SQL tiddler store
\*/
(function(){
/*jslint node: true, browser: true */
/*global $tw: false */
"use strict";
if($tw.node) {
describe("SQL tiddler store", function() {
// Create and initialise the tiddler store
var SqlTiddlerStore = require("$:/plugins/tiddlywiki/multiwikiserver/sql-tiddler-store.js").SqlTiddlerStore;
const sqlTiddlerStore = new SqlTiddlerStore({
adminWiki: new $tw.Wiki()
});
sqlTiddlerStore.createTables();
// Create bags and recipes
sqlTiddlerStore.createBag("bag-alpha");
sqlTiddlerStore.createBag("bag-beta");
sqlTiddlerStore.createBag("bag-gamma");
sqlTiddlerStore.createRecipe("recipe-rho",["bag-alpha","bag-beta"]);
sqlTiddlerStore.createRecipe("recipe-sigma",["bag-alpha","bag-gamma"]);
sqlTiddlerStore.createRecipe("recipe-tau",["bag-alpha"]);
sqlTiddlerStore.createRecipe("recipe-upsilon",["bag-alpha","bag-gamma","bag-beta"]);
// Tear down
afterAll(function() {
// Close the database
sqlTiddlerStore.close();
});
// Run tests
it("should save and retrieve tiddlers", function() {
// Save tiddlers
sqlTiddlerStore.saveBagTiddler({title: "Another Tiddler",text: "I'm in alpha",tags: "one two three"},"bag-alpha");
sqlTiddlerStore.saveBagTiddler({title: "Hello There",text: "I'm in alpha as well",tags: "one two three"},"bag-alpha");
sqlTiddlerStore.saveBagTiddler({title: "Hello There",text: "I'm in beta",tags: "four five six"},"bag-beta");
sqlTiddlerStore.saveBagTiddler({title: "Hello There",text: "I'm in gamma",tags: "seven eight nine"},"bag-gamma");
// Verify what we've got
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-rho")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-beta' }
]);
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-sigma")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-gamma' }
]);
expect(sqlTiddlerStore.getRecipeTiddler("Hello There","recipe-rho").tiddler).toEqual({ title: "Hello There", text: "I'm in beta", tags: "four five six" });
expect(sqlTiddlerStore.getRecipeTiddler("Missing Tiddler","recipe-rho")).toEqual(null);
expect(sqlTiddlerStore.getRecipeTiddler("Another Tiddler","recipe-rho").tiddler).toEqual({ title: "Another Tiddler", text: "I'm in alpha", tags: "one two three" });
expect(sqlTiddlerStore.getRecipeTiddler("Hello There","recipe-sigma").tiddler).toEqual({ title: "Hello There", text: "I'm in gamma", tags: "seven eight nine" });
expect(sqlTiddlerStore.getRecipeTiddler("Another Tiddler","recipe-sigma").tiddler).toEqual({ title: "Another Tiddler", text: "I'm in alpha", tags: "one two three" });
expect(sqlTiddlerStore.getRecipeTiddler("Hello There","recipe-upsilon").tiddler).toEqual({title: "Hello There",text: "I'm in beta",tags: "four five six"});
// Delete a tiddlers to ensure the underlying tiddler in the recipe shows through
sqlTiddlerStore.deleteTiddler("Hello There","bag-beta");
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-rho")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-alpha' }
]);
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-sigma")).toEqual([
{ title: 'Another Tiddler', bag_name: 'bag-alpha' },
{ title: 'Hello There', bag_name: 'bag-gamma' }
]);
expect(sqlTiddlerStore.getRecipeTiddler("Hello There","recipe-beta")).toEqual(null);
sqlTiddlerStore.deleteTiddler("Another Tiddler","bag-alpha");
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-rho")).toEqual([ { title: 'Hello There', bag_name: 'bag-alpha' } ]);
expect(sqlTiddlerStore.getRecipeTiddlers("recipe-sigma")).toEqual([ { title: 'Hello There', bag_name: 'bag-gamma' } ]);
// Save a recipe tiddler
expect(sqlTiddlerStore.saveRecipeTiddler({title: "More", text: "None"},"recipe-rho")).toEqual({tiddler_id: 5, bag_name: 'bag-beta'});
expect(sqlTiddlerStore.getRecipeTiddler("More","recipe-rho").tiddler).toEqual({title: "More", text: "None"});
});
});
}
})();