import { mkdir } from "node:fs/promises"; import { Database, SQLiteError } from "bun:sqlite"; import { UserEntry, RecordEntry } from "$lib/db_types"; import { parseDate, isTimeValidHHMM } from "$lib/util"; const DATABASES_PATH: string = ""; const USER_DATABASE_PATH: string = DATABASES_PATH + "users.sqlite"; const CHECK_QUERY: string = "SELECT * FROM sqlite_master;"; const USER_DATABASE_SETUP: string[] = [ "CREATE TABLE IF NOT EXISTS users (id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, name TEXT, created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL);", ] const USER_DATABASE_ADD_USER: string = "INSERT INTO users (name) VALUES ($name);"; const USER_DATABASE_GET_USER: string = "SELECT * FROM users;"; const ENTRY_DATABASE_SETUP: string[] = [ "PRAGMA foreign_keys = ON;", "CREATE TABLE meta (key TEXT PRIMARY KEY NOT NULL, value NUMBER);", "INSERT INTO meta(key, value) VALUES ('triggerActive', 1)", "CREATE TABLE records ( \ id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, \ date VARCHAR(10), \ start VARCHAR(5), \ end VARCHAR(5), \ comment TEXT, \ created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL, \ modified DATETIME DEFAULT NULL, \ modified_to INTEGER UNIQUE DEFAULT NULL, \ FOREIGN KEY(modified_to) REFERENCES records(id) \ );", `CREATE TRIGGER prevent_update_if_superseded BEFORE UPDATE ON records WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1 AND (OLD.modified_to NOT NULL OR OLD.date ISNULL) BEGIN SELECT raise(ABORT, 'Modification on changed row is not allowed'); END;`, "CREATE TRIGGER prevent_update \ BEFORE UPDATE ON records \ WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1 \ BEGIN \ INSERT INTO records(date, start, end, comment) VALUES (NEW.date, NEW.start, NEW.end, NEW.comment); \ UPDATE records SET (modified, modified_to) = (CURRENT_TIMESTAMP, last_insert_rowid()) WHERE NEW.id == id; \ SELECT raise(IGNORE); \ END;", `CREATE TRIGGER prevent_delete BEFORE DELETE ON records BEGIN UPDATE records SET (date, start, end, comment) = (null, null, null, null) WHERE OLD.id = id; SELECT raise(IGNORE); END;` ] const ENTRY_DATABASE_GET_ENTRY_BY_ID: string = "SELECT * FROM records WHERE modified_to ISNULL AND id = $id;" const ENTRY_DATABASE_GET_ENTRIES: string = "SELECT * FROM records WHERE modified_to ISNULL;" const ENTRY_DATABASE_ADD_ENTRY: string = "INSERT INTO records(date, start, end, comment) VALUES ($date, $start, $end, $comment);" const Entry_DATABASE_EDIT_ENTRY: string = "UPDATE records SET date = $date, start = $start, end = $end, comment = $comment WHERE id = $id;"; export class User { user: UserEntry; private database: Database; constructor(user: UserEntry, db: Database) { this.user = user; this._database = db; } get_entries(): Entry[] { const query = this._database.query(ENTRY_DATABASE_GET_ENTRIES); const res = query.all() return res; } get_entry(id: number): Entry { const query = this._database.query(ENTRY_DATABASE_GET_ENTRY_BY_ID); const res = query.get({ id: id }); return res; } insert_entry(date: string, start: string, end: string, comment: string | null) { if (parseDate(date) == null || !isTimeValidHHMM(start) || !isTimeValidHHMM(end)) { return false; } const query = this._database.query(ENTRY_DATABASE_ADD_ENTRY); const res = query.run({ date: date, start: start, end: end, comment: comment }); return res.changes == 1; } update_entry(id: number, ndate: string, nstart: string, nend: string, ncomment: string): RecordEntry | null { if (isNaN(id) || parseDate(ndate) == null || !isTimeValidHHMM(nstart) || !isTimeValidHHMM(nend)) { return null; } const query = this._database.query(Entry_DATABASE_EDIT_ENTRY); const res = query.run({ id: id, date: ndate, start: nstart, end: nend, comment: ncomment }); return res.changes > 1; } } let user_database: Database; function is_db_initialized(db: Database): boolean { try { let res = db.query(CHECK_QUERY).get(); return res != null; } catch (exception) { if (!(exception instanceof SQLiteError)) { throw exception; } console.log(e); return false; } } function get_user_db_name(user: UserEntry) { return DATABASES_PATH + "user-" + user.id + ".sqlite" } function setup_db(db: Database, setup_queries: string[]) { setup_queries.forEach((q) => { db.query(q).run(); }); } export function init_db() { user_database = new Database(USER_DATABASE_PATH, { strict: true, create: true }); if (!is_db_initialized(user_database)) { setup_db(user_database, USER_DATABASE_SETUP); } } export function close_db() { if (user_database) { user_database.close(); } } export function create_user(name: string): boolean { try { const statement = user_database.query(USER_DATABASE_ADD_USER); const result = statement.run({ name: name }); return true; } catch (e) { console.log(e); if (e instanceof SQLiteError) { return false; } throw e; } } function _get_user(): UserEntry { try { const statement = user_database.prepare(USER_DATABASE_GET_USER); const result: UserEntry = statement.get(); if (result == null) { create_user("PM"); return get_user(); } return result; } catch (e) { if (e instanceof SQLiteError) { return false; } throw e; } } export function get_user(): User | null { const user = _get_user(); const db_name = get_user_db_name(user); try { let userdb = new Database(db_name, { create: true, strict: true }); if (!is_db_initialized(userdb)) { setup_db(userdb, ENTRY_DATABASE_SETUP); } return new User(user, userdb); } catch (e) { console.log(e); return null; } }