1
0
mirror of https://github.com/Jermolene/TiddlyWiki5 synced 2025-02-09 15:40:03 +00:00

Refactor the database engine specific code

This commit is contained in:
Jeremy Ruston 2024-03-17 13:27:00 +00:00
parent 347aa4d546
commit 69cc45bf5c
3 changed files with 163 additions and 142 deletions

View File

@ -0,0 +1,134 @@
/*\
title: $:/plugins/tiddlywiki/multiwikiserver/store/sql-engine.js
type: application/javascript
module-type: library
Low level functions to work with the SQLite engine, either via better-sqlite3 or node-sqlite3-wasm.
This class is intended to encapsulate all engine-specific logic.
\*/
(function() {
/*
Create a database engine. Options include:
databasePath - path to the database file (can be ":memory:" or missing to get a temporary database)
engine - wasm | better
*/
function SqlEngine(options) {
options = options || {};
// Initialise transaction mechanism
this.transactionDepth = 0;
// Initialise the statement cache
this.statements = Object.create(null); // Hashmap by SQL text of statement objects
// Choose engine
this.engine = options.engine || "better"; // wasm | better
// Create the database file directories if needed
if(options.databasePath) {
$tw.utils.createFileDirectories(options.databasePath);
}
// Create the database
const databasePath = options.databasePath || ":memory:";
let Database;
switch(this.engine) {
case "wasm":
({ Database } = require("node-sqlite3-wasm"));
break;
case "better":
Database = require("better-sqlite3");
break;
}
this.db = new Database(databasePath,{
verbose: undefined && console.log
});
}
SqlEngine.prototype.close = function() {
for(const sql in this.statements) {
if(this.statements[sql].finalize) {
this.statements[sql].finalize();
}
}
this.statements = Object.create(null);
this.db.close();
this.db = undefined;
};
SqlEngine.prototype.normaliseParams = function(params) {
params = params || {};
const result = Object.create(null);
for(const paramName in params) {
if(this.engine !== "wasm" && paramName.startsWith("$")) {
result[paramName.slice(1)] = params[paramName];
} else {
result[paramName] = params[paramName];
}
}
return result;
};
SqlEngine.prototype.prepareStatement = function(sql) {
if(!(sql in this.statements)) {
this.statements[sql] = this.db.prepare(sql);
}
return this.statements[sql];
};
SqlEngine.prototype.runStatement = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.run(params);
};
SqlEngine.prototype.runStatementGet = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.get(params);
};
SqlEngine.prototype.runStatementGetAll = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.all(params);
};
SqlEngine.prototype.runStatements = function(sqlArray) {
for(const sql of sqlArray) {
this.runStatement(sql);
}
};
/*
Execute the given function in a transaction, committing if successful but rolling back if an error occurs. Returns whatever the given function returns.
Calls to this function can be safely nested, but only the topmost call will actually take place in a transaction.
TODO: better-sqlite3 provides its own transaction method which we should be using if available
*/
SqlEngine.prototype.transaction = function(fn) {
const alreadyInTransaction = this.transactionDepth > 0;
this.transactionDepth++;
try {
if(alreadyInTransaction) {
return fn();
} else {
this.runStatement(`BEGIN TRANSACTION`);
try {
var result = fn();
this.runStatement(`COMMIT TRANSACTION`);
} catch(e) {
this.runStatement(`ROLLBACK TRANSACTION`);
throw(e);
}
return result;
}
} finally {
this.transactionDepth--;
}
};
exports.SqlEngine = SqlEngine;
})();

View File

@ -20,89 +20,24 @@ engine - wasm | better
*/ */
function SqlTiddlerDatabase(options) { function SqlTiddlerDatabase(options) {
options = options || {}; options = options || {};
// Initialise the statement cache const SqlEngine = require("$:/plugins/tiddlywiki/multiwikiserver/store/sql-engine.js").SqlEngine;
this.statements = Object.create(null); // Hashmap by SQL text of statement objects this.engine = new SqlEngine({
// Create the database file directories if needed databasePath: options.databasePath,
if(options.databasePath) { engine: options.engine
$tw.utils.createFileDirectories(options.databasePath);
}
// Choose engine
this.engine = options.engine || "better"; // wasm | better
// Create the database
const databasePath = options.databasePath || ":memory:";
let Database;
console.log(`Creating SQL engine ${this.engine}`)
switch(this.engine) {
case "wasm":
({ Database } = require("node-sqlite3-wasm"));
break;
case "better":
Database = require("better-sqlite3");
break;
}
this.db = new Database(databasePath,{
verbose: undefined && console.log
}); });
this.transactionDepth = 0;
} }
SqlTiddlerDatabase.prototype.close = function() { SqlTiddlerDatabase.prototype.close = function() {
for(const sql in this.statements) { this.engine.close();
if(this.statements[sql].finalize) {
this.statements[sql].finalize();
}
}
this.statements = Object.create(null);
this.db.close();
this.db = undefined;
}; };
SqlTiddlerDatabase.prototype.normaliseParams = function(params) {
params = params || {};
const result = Object.create(null);
for(const paramName in params) {
if(this.engine !== "wasm" && paramName.startsWith("$")) {
result[paramName.slice(1)] = params[paramName];
} else {
result[paramName] = params[paramName];
}
}
return result;
};
SqlTiddlerDatabase.prototype.prepareStatement = function(sql) { SqlTiddlerDatabase.prototype.transaction = function(fn) {
if(!(sql in this.statements)) { return this.engine.transaction(fn);
this.statements[sql] = this.db.prepare(sql);
}
return this.statements[sql];
};
SqlTiddlerDatabase.prototype.runStatement = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.run(params);
};
SqlTiddlerDatabase.prototype.runStatementGet = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.get(params);
};
SqlTiddlerDatabase.prototype.runStatementGetAll = function(sql,params) {
params = this.normaliseParams(params);
const statement = this.prepareStatement(sql);
return statement.all(params);
};
SqlTiddlerDatabase.prototype.runStatements = function(sqlArray) {
for(const sql of sqlArray) {
this.runStatement(sql);
}
}; };
SqlTiddlerDatabase.prototype.createTables = function() { SqlTiddlerDatabase.prototype.createTables = function() {
this.runStatements([` this.engine.runStatements([`
-- Bags have names and access control settings -- Bags have names and access control settings
CREATE TABLE IF NOT EXISTS bags ( CREATE TABLE IF NOT EXISTS bags (
bag_id INTEGER PRIMARY KEY AUTOINCREMENT, bag_id INTEGER PRIMARY KEY AUTOINCREMENT,
@ -149,23 +84,8 @@ SqlTiddlerDatabase.prototype.createTables = function() {
`]); `]);
}; };
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() { SqlTiddlerDatabase.prototype.listBags = function() {
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT bag_name, accesscontrol, description SELECT bag_name, accesscontrol, description
FROM bags FROM bags
ORDER BY bag_name ORDER BY bag_name
@ -176,13 +96,13 @@ SqlTiddlerDatabase.prototype.listBags = function() {
SqlTiddlerDatabase.prototype.createBag = function(bagname,description,accesscontrol) { SqlTiddlerDatabase.prototype.createBag = function(bagname,description,accesscontrol) {
accesscontrol = accesscontrol || ""; accesscontrol = accesscontrol || "";
// Run the queries // Run the queries
this.runStatement(` this.engine.runStatement(`
INSERT OR IGNORE INTO bags (bag_name, accesscontrol, description) INSERT OR IGNORE INTO bags (bag_name, accesscontrol, description)
VALUES ($bag_name, '', '') VALUES ($bag_name, '', '')
`,{ `,{
$bag_name: bagname $bag_name: bagname
}); });
this.runStatement(` this.engine.runStatement(`
UPDATE bags UPDATE bags
SET accesscontrol = $accesscontrol, SET accesscontrol = $accesscontrol,
description = $description description = $description
@ -198,7 +118,7 @@ SqlTiddlerDatabase.prototype.createBag = function(bagname,description,accesscont
Returns array of {recipe_name:,description:,bag_names: []} Returns array of {recipe_name:,description:,bag_names: []}
*/ */
SqlTiddlerDatabase.prototype.listRecipes = function() { SqlTiddlerDatabase.prototype.listRecipes = function() {
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT r.recipe_name, r.description, b.bag_name, rb.position SELECT r.recipe_name, r.description, b.bag_name, rb.position
FROM recipes AS r FROM recipes AS r
JOIN recipe_bags AS rb ON rb.recipe_id = r.recipe_id JOIN recipe_bags AS rb ON rb.recipe_id = r.recipe_id
@ -224,13 +144,13 @@ SqlTiddlerDatabase.prototype.listRecipes = function() {
SqlTiddlerDatabase.prototype.createRecipe = function(recipename,bagnames,description) { SqlTiddlerDatabase.prototype.createRecipe = function(recipename,bagnames,description) {
// Run the queries // Run the queries
this.runStatement(` this.engine.runStatement(`
-- Delete existing recipe_bags entries for this recipe -- 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) DELETE FROM recipe_bags WHERE recipe_id = (SELECT recipe_id FROM recipes WHERE recipe_name = $recipe_name)
`,{ `,{
$recipe_name: recipename $recipe_name: recipename
}); });
this.runStatement(` this.engine.runStatement(`
-- Create the entry in the recipes table if required -- Create the entry in the recipes table if required
INSERT OR REPLACE INTO recipes (recipe_name, description) INSERT OR REPLACE INTO recipes (recipe_name, description)
VALUES ($recipe_name, $description) VALUES ($recipe_name, $description)
@ -238,7 +158,7 @@ SqlTiddlerDatabase.prototype.createRecipe = function(recipename,bagnames,descrip
$recipe_name: recipename, $recipe_name: recipename,
$description: description $description: description
}); });
this.runStatement(` this.engine.runStatement(`
INSERT INTO recipe_bags (recipe_id, bag_id, position) INSERT INTO recipe_bags (recipe_id, bag_id, position)
SELECT r.recipe_id, b.bag_id, j.key as position SELECT r.recipe_id, b.bag_id, j.key as position
FROM recipes r FROM recipes r
@ -257,7 +177,7 @@ Returns {tiddler_id:}
SqlTiddlerDatabase.prototype.saveBagTiddler = function(tiddlerFields,bagname,attachment_blob) { SqlTiddlerDatabase.prototype.saveBagTiddler = function(tiddlerFields,bagname,attachment_blob) {
attachment_blob = attachment_blob || null; attachment_blob = attachment_blob || null;
// Update the tiddlers table // Update the tiddlers table
var info = this.runStatement(` var info = this.engine.runStatement(`
INSERT OR REPLACE INTO tiddlers (bag_id, title, attachment_blob) INSERT OR REPLACE INTO tiddlers (bag_id, title, attachment_blob)
VALUES ( VALUES (
(SELECT bag_id FROM bags WHERE bag_name = $bag_name), (SELECT bag_id FROM bags WHERE bag_name = $bag_name),
@ -270,7 +190,7 @@ SqlTiddlerDatabase.prototype.saveBagTiddler = function(tiddlerFields,bagname,att
$bag_name: bagname $bag_name: bagname
}); });
// Update the fields table // Update the fields table
this.runStatement(` this.engine.runStatement(`
INSERT OR REPLACE INTO fields (tiddler_id, field_name, field_value) INSERT OR REPLACE INTO fields (tiddler_id, field_name, field_value)
SELECT SELECT
t.tiddler_id, t.tiddler_id,
@ -301,7 +221,7 @@ Returns {tiddler_id:,bag_name:} or null if the recipe is empty
*/ */
SqlTiddlerDatabase.prototype.saveRecipeTiddler = function(tiddlerFields,recipename,attachment_blob) { SqlTiddlerDatabase.prototype.saveRecipeTiddler = function(tiddlerFields,recipename,attachment_blob) {
// Find the topmost bag in the recipe // Find the topmost bag in the recipe
var row = this.runStatementGet(` var row = this.engine.runStatementGet(`
SELECT b.bag_name SELECT b.bag_name
FROM bags AS b FROM bags AS b
JOIN ( JOIN (
@ -332,7 +252,7 @@ SqlTiddlerDatabase.prototype.saveRecipeTiddler = function(tiddlerFields,recipena
SqlTiddlerDatabase.prototype.deleteTiddler = function(title,bagname) { SqlTiddlerDatabase.prototype.deleteTiddler = function(title,bagname) {
// Run the queries // Run the queries
this.runStatement(` this.engine.runStatement(`
DELETE FROM fields DELETE FROM fields
WHERE tiddler_id IN ( WHERE tiddler_id IN (
SELECT t.tiddler_id SELECT t.tiddler_id
@ -344,7 +264,7 @@ SqlTiddlerDatabase.prototype.deleteTiddler = function(title,bagname) {
$title: title, $title: title,
$bag_name: bagname $bag_name: bagname
}); });
this.runStatement(` this.engine.runStatement(`
DELETE FROM tiddlers DELETE FROM tiddlers
WHERE bag_id = ( WHERE bag_id = (
SELECT bag_id SELECT bag_id
@ -361,7 +281,7 @@ SqlTiddlerDatabase.prototype.deleteTiddler = function(title,bagname) {
returns {tiddler_id:,tiddler:,attachment_blob:} returns {tiddler_id:,tiddler:,attachment_blob:}
*/ */
SqlTiddlerDatabase.prototype.getBagTiddler = function(title,bagname) { SqlTiddlerDatabase.prototype.getBagTiddler = function(title,bagname) {
const rowTiddler = this.runStatementGet(` const rowTiddler = this.engine.runStatementGet(`
SELECT t.tiddler_id, t.attachment_blob SELECT t.tiddler_id, t.attachment_blob
FROM bags AS b FROM bags AS b
INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id INNER JOIN tiddlers AS t ON b.bag_id = t.bag_id
@ -373,7 +293,7 @@ SqlTiddlerDatabase.prototype.getBagTiddler = function(title,bagname) {
if(!rowTiddler) { if(!rowTiddler) {
return null; return null;
} }
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT field_name, field_value, tiddler_id SELECT field_name, field_value, tiddler_id
FROM fields FROM fields
WHERE tiddler_id = $tiddler_id WHERE tiddler_id = $tiddler_id
@ -398,7 +318,7 @@ SqlTiddlerDatabase.prototype.getBagTiddler = function(title,bagname) {
Returns {bag_name:, tiddler: {fields}, tiddler_id:, attachment_blob:} Returns {bag_name:, tiddler: {fields}, tiddler_id:, attachment_blob:}
*/ */
SqlTiddlerDatabase.prototype.getRecipeTiddler = function(title,recipename) { SqlTiddlerDatabase.prototype.getRecipeTiddler = function(title,recipename) {
const rowTiddlerId = this.runStatementGet(` const rowTiddlerId = this.engine.runStatementGet(`
SELECT t.tiddler_id, t.attachment_blob, b.bag_name SELECT t.tiddler_id, t.attachment_blob, b.bag_name
FROM bags AS b FROM bags AS b
INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id INNER JOIN recipe_bags AS rb ON b.bag_id = rb.bag_id
@ -416,7 +336,7 @@ SqlTiddlerDatabase.prototype.getRecipeTiddler = function(title,recipename) {
return null; return null;
} }
// Get the fields // Get the fields
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT field_name, field_value SELECT field_name, field_value
FROM fields FROM fields
WHERE tiddler_id = $tiddler_id WHERE tiddler_id = $tiddler_id
@ -438,7 +358,7 @@ SqlTiddlerDatabase.prototype.getRecipeTiddler = function(title,recipename) {
Get the titles of the tiddlers in a bag. Returns an empty array for bags that do not exist Get the titles of the tiddlers in a bag. Returns an empty array for bags that do not exist
*/ */
SqlTiddlerDatabase.prototype.getBagTiddlers = function(bagname) { SqlTiddlerDatabase.prototype.getBagTiddlers = function(bagname) {
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT DISTINCT title SELECT DISTINCT title
FROM tiddlers FROM tiddlers
WHERE bag_id IN ( WHERE bag_id IN (
@ -457,7 +377,7 @@ SqlTiddlerDatabase.prototype.getBagTiddlers = function(bagname) {
Get the titles of the tiddlers in a recipe as {title:,bag_name:}. Returns null for recipes that do not exist Get the titles of the tiddlers in a recipe as {title:,bag_name:}. Returns null for recipes that do not exist
*/ */
SqlTiddlerDatabase.prototype.getRecipeTiddlers = function(recipename) { SqlTiddlerDatabase.prototype.getRecipeTiddlers = function(recipename) {
const rowsCheckRecipe = this.runStatementGetAll(` const rowsCheckRecipe = this.engine.runStatementGetAll(`
SELECT * FROM recipes WHERE recipes.recipe_name = $recipe_name SELECT * FROM recipes WHERE recipes.recipe_name = $recipe_name
`,{ `,{
$recipe_name: recipename $recipe_name: recipename
@ -465,7 +385,7 @@ SqlTiddlerDatabase.prototype.getRecipeTiddlers = function(recipename) {
if(rowsCheckRecipe.length === 0) { if(rowsCheckRecipe.length === 0) {
return null; return null;
} }
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT title, bag_name SELECT title, bag_name
FROM ( FROM (
SELECT t.title, b.bag_name, MAX(rb.position) AS position SELECT t.title, b.bag_name, MAX(rb.position) AS position
@ -484,7 +404,7 @@ SqlTiddlerDatabase.prototype.getRecipeTiddlers = function(recipename) {
}; };
SqlTiddlerDatabase.prototype.deleteAllTiddlersInBag = function(bagname) { SqlTiddlerDatabase.prototype.deleteAllTiddlersInBag = function(bagname) {
this.runStatement(` this.engine.runStatement(`
DELETE FROM tiddlers DELETE FROM tiddlers
WHERE bag_id IN ( WHERE bag_id IN (
SELECT bag_id SELECT bag_id
@ -500,7 +420,7 @@ SqlTiddlerDatabase.prototype.deleteAllTiddlersInBag = function(bagname) {
Get the names of the bags in a recipe. Returns an empty array for recipes that do not exist Get the names of the bags in a recipe. Returns an empty array for recipes that do not exist
*/ */
SqlTiddlerDatabase.prototype.getRecipeBags = function(recipename) { SqlTiddlerDatabase.prototype.getRecipeBags = function(recipename) {
const rows = this.runStatementGetAll(` const rows = this.engine.runStatementGetAll(`
SELECT bags.bag_name SELECT bags.bag_name
FROM bags FROM bags
JOIN ( JOIN (
@ -517,35 +437,6 @@ SqlTiddlerDatabase.prototype.getRecipeBags = function(recipename) {
return rows.map(value => value.bag_name); return rows.map(value => value.bag_name);
}; };
/*
Execute the given function in a transaction, committing if successful but rolling back if an error occurs. Returns whatever the given function returns.
Calls to this function can be safely nested, but only the topmost call will actually take place in a transaction.
TODO: better-sqlite3 provides its own transaction method which we should be using if available
*/
SqlTiddlerDatabase.prototype.transaction = function(fn) {
const alreadyInTransaction = this.transactionDepth > 0;
this.transactionDepth++;
try {
if(alreadyInTransaction) {
return fn();
} else {
this.runStatement(`BEGIN TRANSACTION`);
try {
var result = fn();
this.runStatement(`COMMIT TRANSACTION`);
} catch(e) {
this.runStatement(`ROLLBACK TRANSACTION`);
throw(e);
}
return result;
}
} finally {
this.transactionDepth--;
}
};
exports.SqlTiddlerDatabase = SqlTiddlerDatabase; exports.SqlTiddlerDatabase = SqlTiddlerDatabase;
})(); })();

View File

@ -170,10 +170,6 @@ SqlTiddlerStore.prototype.saveTiddlersFromPath = function(tiddler_files_path,bag
}); });
}; };
SqlTiddlerStore.prototype.logTables = function() {
this.sqlTiddlerDatabase.logTables();
};
SqlTiddlerStore.prototype.listBags = function() { SqlTiddlerStore.prototype.listBags = function() {
return this.sqlTiddlerDatabase.listBags(); return this.sqlTiddlerDatabase.listBags();
}; };