Stundenaufzeichnung/src/lib/server/database.ts

634 lines
19 KiB
TypeScript

import fs from "node:fs/promises";
import { Database, SQLiteError } from "bun:sqlite";
import type { UserEntry, RecordEntry, EstimatesEntry } from "$lib/db_types";
import { calculateDuration, parseDate, toInt, isTimeValidHHMM } from "$lib/util";
import Logs from "$lib/server/log"
const DATABASES_PATH: string = (process.env.APP_USER_DATA_PATH ?? ".") + "/databases/";
const USER_DATABASE_PATH: string = DATABASES_PATH + "users.sqlite";
const CHECK_QUERY: string =
"SELECT * FROM sqlite_master;";
const USER_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 IF NOT EXISTS users (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
name TEXT,
gender TEXT,
address TEXT,
username TEXT UNIQUE,
password TEXT,
permissions INTEGER DEFAULT 0,
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
);`,
`CREATE TABLE IF NOT EXISTS users_history (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
user_id INTEGER,
name TEXT,
gender TEXT,
address TEXT,
username TEXT,
permissions INTEGER DEFAULT 0,
created DATETIME NOT NULL,
deleted DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
FOREIGN KEY (user_id) REFERENCES users(id)
);`,
`CREATE TRIGGER user_delete_history
BEFORE DELETE ON users
WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1
BEGIN
INSERT INTO users_history(user_id, name, gender, address, username, permissions, created) VALUES (OLD.id, OLD.name, OLD.gender, OLD.address, OLD.username, OLD.permissions, OLD.created);
END;`,
`CREATE TABLE refresh_tokens (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
user_id INTEGER NOT NULL,
token TEXT UNIQUE,
expiry_date DATETIME,
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
FOREIGN KEY(user_id) REFERENCES users(id)
);`,
/*`CREATE TABLE session_tokens (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
user_id INTEGER NOT NULL,
create_token_id INTEGER NOT NULL,
token TEXT UNIQUE,
expiry_date DATETIME,
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
FOREIGN KEY(user_id) REFERENCES users(id),
FOREIGN KEY(create_token_id) REFERENCES access_tokens(id)
);`,*/
];
const USER_DATABASE_ADD_USER: string =
"INSERT INTO users (name, gender, address, username, password) VALUES ($name, $gender, $address, $username, $password);";
const USER_DATABASE_ADD_USER_WITH_PERMISSIONS: string =
"INSERT INTO users (name, gender, address, username, password, permissions) VALUES ($name, $gender, $address, $username, $password, $permissions);";
const USER_DATABASE_GET_ALL_USER: string =
"SELECT id, username, name FROM users;";
const USER_DATABASE_GET_USER_BY_ID: string =
"SELECT * FROM users WHERE id = $id;"
const USER_DATABASE_GET_USER_BY_NAME: string =
"SELECT * FROM users WHERE username = $username;"
const USER_DATABASE_EMPTY: string =
"SELECT EXISTS (SELECT 1 FROM users);"
const USER_DATABASE_UPDATE_PASSWORD: string =
"UPDATE users SET password=$password WHERE id=$id;"
const USER_DATABASE_REMOVE_USER: string =
"DELETE FROM users WHERE id = $id;"
/*const USER_DATABASE_ADD_ACCESS_TOKEN: string =
"INSERT INTO access_tokens (user_id, token, expiry_date) VALUES ($user_id, $token, $expiry_date);"
const USER_DATABASE_REMOVE_ACCESS_TOKEN: string =
"UPDATE access_tokens SET expiry_date = NULL WHERE token = $token;"*/
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,
UNIQUE (date, start, end)
);`,
`CREATE TABLE records_history (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
record_id INTEGER NOT NULL,
date VARCHAR(10),
start VARCHAR(5),
end VARCHAR(5),
comment TEXT,
modified DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
FOREIGN KEY(record_id) REFERENCES records(id)
);`,
`CREATE TRIGGER records_update_history
BEFORE UPDATE ON records
WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1
BEGIN
INSERT INTO records_history(record_id, date, start, end, comment) VALUES (OLD.id, OLD.date, OLD.start, OLD.end, OLD.comment);
END;`,
`CREATE TRIGGER records_delete_history
BEFORE DELETE ON records
WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1
BEGIN
INSERT INTO records_history(record_id, date, start, end, comment) VALUES (OLD.id, OLD.date, OLD.start, OLD.end, OLD.comment);
END;`,
`CREATE TABLE estimates (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
year INTEGER NOT NULL,
quarter INTEGER NOT NULL,
estimate_0 REAL,
estimate_1 REAL,
estimate_2 REAL,
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
UNIQUE(year, quarter)
);`,
`CREATE TABLE estimates_history (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
estimate_id INTEGER NOT NULL,
year INTEGER NOT NULL,
quarter INTEGER NOT NULL,
estimate_0 REAL NOT NULL,
estimate_1 REAL NOT NULL,
estimate_2 REAL NOT NULL,
modified DATETIME DEFAULT NULL,
FOREIGN KEY(estimate_id) REFERENCES estimates(id)
);`,
`CREATE TRIGGER estimates_update_history
BEFORE UPDATE ON estimates
WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1
BEGIN
INSERT INTO estimates_history(estimate_id, year, quarter, estimate_0, estimate_1, estimate_2) VALUES (OLD.id, OLD.year, OLD.quarter, OLD.estimate_0, OLD.estimate_1, OLD.estimate_2);
END;`,
`CREATE TRIGGER estimates_delete_history
BEFORE DELETE ON estimates
WHEN (SELECT value FROM meta WHERE key = 'triggerActive') = 1
BEGIN
INSERT INTO estimates_history(estimate_id, year, quarter, estimate_0, estimate_1, estimate_2) VALUES (OLD.id, OLD.year, OLD.quarter, OLD.estimate_0, OLD.estimate_1, OLD.estimate_2);
END;`,
]
const ENTRY_DATABASE_GET_MONTHS: string =
"SELECT DISTINCT SUBSTR(date, 7, 4) as year, SUBSTR(date, 4, 2) as month FROM records ORDER BY year DESC, month DESC;"
const ENTRY_DATABASE_GET_ENTRY_BY_ID: string =
"SELECT * FROM records WHERE id = $id;"
const ENTRY_DATABASE_GET_ENTRIES_IN_MONTH: string =
"SELECT * FROM records WHERE SUBSTR(date, 7, 4) = $year AND SUBSTR(date, 4, 2) = $month ORDER BY SUBSTR(date, 1, 2);"
const ENTRY_DATABASE_GET_ENTRIES: string =
"SELECT * FROM records ORDER BY SUBSTR(date, 7, 4) DESC, SUBSTR(date, 4, 2) DESC, SUBSTR(date, 1, 2) DESC;"
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;";
const ENTRY_DATABASE_REMOVE_ENTRY: string =
"DELETE FROM records WHERE id = $id;";
const ENTRY_DATABASE_EXPORT: string =
"SELECT date, start, end, comment FROM records;"
const ENTRY_DATABASE_IMPORT: string =
"INSERT OR IGNORE INTO records(date, start, end, comment) VALUES ($date, $start, $end, $comment);"
const ESTIMATES_DATABASE_GET_ALL: string =
"SELECT * FROM estimates ORDER BY year DESC, quarter DESC;"
const ESTIMATES_DATABASE_GET_QUARTERS: string =
"SELECT year, quarter FROM estimates;"
const ESTIMATES_DATABASE_GET_QUART: string =
"SELECT estimate_0, estimate_1, estimate_2 FROM estimates WHERE year = $year AND quarter = $quarter;"
const ESTIMATES_DATABASE_INSERT: string =
"INSERT INTO estimates(year, quarter, estimate_0, estimate_1, estimate_2) VALUES ($year, $quarter, $estimate_0, $estimate_1, $estimate_2);"
const ESTIMATES_DATABASE_EXPORT: string =
"SELECT year, quarter, estimate_0, estimate_1, estimate_2 FROM estimates;"
const ESTIMATES_DATABASE_IMPORT: string =
"INSERT OR IGNORE INTO estimates(year, quarter, estimate_0, estimate_1, estimate_2) VALUES ($year, $quarter, $estimate_0, $estimate_1, $estimate_2);"
export class User {
id: number;
gender: string;
name: string;
address: string;
username: string;
password: string;
permissions: number;
created: string;
private _database: Database;
constructor(user: UserEntry, db: Database) {
this.id = user.id;
this.gender = user.gender;
this.name = user.name;
this.address = user.address;
this.username = user.username;
this.password = user.password;
this.permissions = user.permissions;
this.created = user.created;
this._database = db;
}
toUserEntry(): UserEntry {
return {
id: this.id,
gender: this.gender,
name: this.name,
address: this.address,
username: this.username,
password: this.password,
permissions: this.permissions,
created: this.created,
}
}
get_months(): { year: number, month: number }[] {
const query = this._database.query(ENTRY_DATABASE_GET_MONTHS);
const res = query.all() as { year: string, month: string }[];
const ret = res.map((v) => { return { year: toInt(v.year), month: toInt(v.month) }})
return ret;
}
get_quarters(): { year: number, quarter: number }[] {
const query = this._database.query(ESTIMATES_DATABASE_GET_QUARTERS)
const res = query.all() as { year: number, quarter: number }[];
return res;
}
get_hr_sum(year: number, month: number): number {
const months = this.get_entries_by_month(year, month);
let sum = 0;
months.forEach((record) => { sum += calculateDuration(record.start, record.end) })
return sum;
}
get_entries(): Entry[] {
const query = this._database.query(ENTRY_DATABASE_GET_ENTRIES);
const res = query.all()
return res;
}
get_entries_by_month(year: number, month: number): RecordEntry[] {
if (!(month > 0 && month < 13)) {
return [];
}
const query = this._database.query(ENTRY_DATABASE_GET_ENTRIES_IN_MONTH);
const res = query.all({ year: year.toString(), month: month.toString().padStart(2, '0') }) as RecordEntry[];
return res;
}
get_entry(id: number): RecordEntry {
const query = this._database.query(ENTRY_DATABASE_GET_ENTRY_BY_ID);
const res = query.get({ id: id }) as RecordEntry;
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): boolean {
if (isNaN(id) || parseDate(ndate) == null || !isTimeValidHHMM(nstart) || !isTimeValidHHMM(nend)) {
return false;
}
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;
}
remove_entry(id: number): boolean {
if (isNaN(id)) {
return false;
}
const query = this._database.query(ENTRY_DATABASE_REMOVE_ENTRY);
const res = query.run({ id: id });
return res.changes > 1;
}
get_estimates(): Array<EstimatesEntry> {
const query = this._database.query(ESTIMATES_DATABASE_GET_ALL);
const res = query.all() as EstimatesEntry[];
return res;
}
get_estimate(year: number, quarter: number): EstimatesEntry {
const query = this._database.query(ESTIMATES_DATABASE_GET_QUART);
const res = query.get({ year: year, quarter: quarter }) as EstimatesEntry;
return res;
}
get_estimate_by_month(year: number, month: number): number {
const query = this._database.query(ESTIMATES_DATABASE_GET_QUART);
const res = query.get({ year: year, quarter: Math.floor((month-1) / 3)+1 }) as EstimatesEntry;
return res?.[`estimate_${(month - 1) % 3}`] ?? NaN;
}
insert_estimate(year: number, quarter: number, estimate_0: number, estimate_1: number, estimate_2: number) {
if (isNaN(year) || isNaN(quarter) || quarter < 1 || quarter > 4 || isNaN(estimate_0) || isNaN(estimate_1) || isNaN(estimate_2)) {
return null;
}
const query = this._database.query(ESTIMATES_DATABASE_INSERT);
const res = query.run({ year: year, quarter: quarter, estimate_0: estimate_0, estimate_1: estimate_1, estimate_2: estimate_2 });
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;
}
return false;
}
}
function get_user_db_name(user_id: number) {
return DATABASES_PATH + "user-" + user_id + ".sqlite"
}
function setup_db(db: Database, setup_queries: string[]) {
db.transaction(() => {
setup_queries.forEach((q) => { db.query(q).run(); });
})()
}
export async function init_db() {
const stdout = await fs.mkdir(DATABASES_PATH, { recursive: true });
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 async function create_user(user: { name: string, gender: string, address: string, username: string, password: string, permissions?: number }): Promise<number | bigint> {
user.password = await Bun.password.hash(user.password, { algorithm: "bcrypt", cost: 11});
const statement = user.permissions != null
? user_database.query(USER_DATABASE_ADD_USER_WITH_PERMISSIONS)
: user_database.query(USER_DATABASE_ADD_USER);
const result = statement.run(user);
return result.lastInsertRowid;
}
export function get_all_user(): { id: number, username: string, name: string }[] {
try {
const query = user_database.prepare(USER_DATABASE_GET_ALL_USER)
const user = query.all() as { id: number, username: string, name: string }[]
return user
} catch (e) {
throw e
}
}
export function get_user_entry_by_id(id: number): UserEntry | null {
try {
const query = user_database.query(USER_DATABASE_GET_USER_BY_ID)
const user = query.get({ id: id }) as UserEntry | null;
return user
} catch (e) {
Logs.db.error(`Encountered exception when retrievieng user ${id} from database: ${e.message}`)
}
return null
}
export function get_user_by_name(username: string): User | null {
try {
const query = user_database.prepare(USER_DATABASE_GET_USER_BY_NAME);
const user = query.get({ username: username }) as UserEntry | null ;
if (!user) {
return null;
}
fs.mkdir(DATABASES_PATH, { recursive: true });
let userdb = new Database(get_user_db_name(user.id), { create: true, strict: true });
if (!is_db_initialized(userdb)) {
setup_db(userdb, ENTRY_DATABASE_SETUP);
}
return new User(user, userdb);
} catch (exception) {
if (!(exception instanceof SQLiteError)) {
throw exception;
}
}
return null;
}
export function do_users_exist(): any {
const answer = user_database.prepare(USER_DATABASE_EMPTY).get();
// sqlite trims the first "SELECT " and ";" from the query string
return (answer as any)?.[USER_DATABASE_EMPTY.slice(7, -1)];
}
export function updateUser(data: {id: number, gender?: string, name?: string, address?: string, username?: string, permissions?: number }) {
let changed: Array<string> = []
if (data.gender) changed.push("gender=$gender")
if (data.name) changed.push("name=$name")
if (data.address) changed.push("address=$address")
if (data.username) changed.push("username=$username")
if (data.permissions) changed.push("permissions=$permissions")
const update_query = "UPDATE users SET " + changed.join(", ") + " WHERE id=$id;"
const query = user_database.prepare(update_query)
const result = query.run(data)
const user_entry = get_user_entry_by_id(data.id)
if (!user_entry) {
throw new Error("Failed to retrieve updated user")
}
return new User(user_entry, new Database(get_user_db_name(data.id), { create: false, strict: true }) ) // Database should already exist
}
export function update_user_password(user_id: number, password: string) {
const query = user_database.prepare(USER_DATABASE_UPDATE_PASSWORD)
const result = query.run({ password: password, id: user_id })
return result.changes > 0
}
export function remove_user(user_id: number) {
const query = user_database.prepare(USER_DATABASE_REMOVE_USER)
const result = query.run({ id: user_id })
return result.changes > 0
}
type ExportEstimatesEntry = Pick<EstimatesEntry, Exclude<keyof EstimatesEntry, "id" | "created">>
type ExportRecordsEntry = Pick<RecordEntry, Exclude<keyof RecordEntry, "id" | "created">>
export async function export_user_data(user_id: number): Promise<string | null> {
const db_name = get_user_db_name(user_id)
if (!(await fs.exists(db_name))) {
return null
}
const userdb = new Database(db_name, { create: false, strict: true });
let user_data: { id: number } & Partial<{ estimates: Array<ExportEstimatesEntry>, records: Array<ExportRecordsEntry> }> = { id: user_id }
try {
user_data.estimates = userdb.query(ESTIMATES_DATABASE_EXPORT).all() as Array<ExportEstimatesEntry>
} catch (e) {
if (!(e instanceof SQLiteError)) {
throw e
}
}
try {
user_data.records = userdb.query(ENTRY_DATABASE_EXPORT).all() as Array<ExportRecordsEntry>
} catch (e) {
if (!(e instanceof SQLiteError)) {
throw e
}
}
return JSON.stringify(user_data)
}
export async function import_user_data(data: Partial<{ id: number, estimates: Array<unknown>, records: Array<unknown> }>) {
// null or unknown ar of type object
if (!data.id || !(typeof data.id === "number")) {
throw new Error("Invalid JSON: id")
}
if (data.estimates != null) {
if (!(Array.isArray(data.estimates))) {
throw new Error("Invalid JSON: estimates")
}
if (!data.estimates.every((v: unknown): v is ExportEstimatesEntry =>
typeof v === "object"
&& v != null
&& "year" in v
&& "quarter" in v
&& "estimate_0" in v
&& "estimate_1" in v
&& "estimate_2" in v
&& typeof v.year === "number"
&& typeof v.quarter === "number"
&& (typeof v.estimate_0 === "number" || v.estimate_0 == null)
&& (typeof v.estimate_1 === "number" || v.estimate_1 == null)
&& (typeof v.estimate_2 === "number" || v.estimate_2 == null))) {
throw new Error("Invalid JSON: estimates entry")
}
}
if (data.records != null) {
if (!(Array.isArray(data.records))) {
throw new Error("Invalid JSON: records")
}
if (!data.records.every((v: unknown): v is ExportRecordsEntry =>
typeof v === "object"
&& v != null
&& "date" in v
&& "start" in v
&& "end" in v
&& "comment" in v
&& typeof v.date === "string"
&& typeof v.start === "string"
&& typeof v.end === "string"
&& typeof v.comment === "string")) {
throw new Error("Invalid JSON: records entry")
}
}
const user_database_name = get_user_db_name(data.id)
const user_database = new Database(user_database_name, { strict: true })
user_database.transaction((records: Array<ExportRecordsEntry> | null, estimates: Array<ExportEstimatesEntry> | null) => {
if (records != null) {
const query = user_database.prepare(ENTRY_DATABASE_IMPORT)
for (const record of records) { query.run(record) }
}
if (estimates != null) {
const query = user_database.prepare(ESTIMATES_DATABASE_IMPORT)
for (const estimate of estimates) { query.run(estimate) }
}
})(data.records, data.estimates)
}