316 lines
12 KiB
TypeScript
316 lines
12 KiB
TypeScript
// Identity. Store your memories and mental belongings
|
|
// Copyright (C) 2024 Sofía Aritz
|
|
//
|
|
// This program is free software: you can redistribute it and/or modify
|
|
// it under the terms of the GNU Affero General Public License as published
|
|
// by the Free Software Foundation, either version 3 of the License, or
|
|
// (at your option) any later version.
|
|
//
|
|
// This program is distributed in the hope that it will be useful,
|
|
// but WITHOUT ANY WARRANTY; without even the implied warranty of
|
|
// MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
|
// GNU Affero General Public License for more details.
|
|
//
|
|
// You should have received a copy of the GNU Affero General Public License
|
|
// along with this program. If not, see <https://www.gnu.org/licenses/>.
|
|
|
|
import { drizzle } from "drizzle-orm/better-sqlite3";
|
|
import Database from "better-sqlite3";
|
|
import { SQLITE_PATH } from "./consts.js";
|
|
import { sqliteTable } from "drizzle-orm/sqlite-core";
|
|
import { text, integer } from "drizzle-orm/sqlite-core";
|
|
import { asc, desc, eq, sql } from "drizzle-orm";
|
|
|
|
export type DatabaseInterface = Awaited<ReturnType<typeof startDatabase>>
|
|
|
|
export function toDBList(input: any[]): string {
|
|
return JSON.stringify(input);
|
|
}
|
|
|
|
export function fromDBList<T>(input: string): Array<T> {
|
|
return JSON.parse(input)
|
|
}
|
|
|
|
export async function startDatabase() {
|
|
let sqlite = new Database(SQLITE_PATH);
|
|
let database = drizzle(sqlite);
|
|
|
|
const limits = sqliteTable("limits", {
|
|
id: text("id").primaryKey(),
|
|
currentAssetCount: integer("current_asset_count").notNull(),
|
|
maxAssetCount: integer("max_asset_count").notNull(),
|
|
});
|
|
|
|
const users = sqliteTable("users", {
|
|
id: text("id").primaryKey(),
|
|
createdAt: integer("created_at").notNull(),
|
|
lastConnected: integer("last_connected_at").notNull(),
|
|
name: text("name").notNull(),
|
|
email: text("email").notNull(),
|
|
password: text("password").notNull(),
|
|
assets: text("assets").notNull(),
|
|
limitID: text("limits")
|
|
.notNull()
|
|
.references(() => limits.id),
|
|
});
|
|
|
|
const session_keys = sqliteTable("session_keys", {
|
|
key: text("key").primaryKey(),
|
|
userID: text("user_id")
|
|
.notNull()
|
|
.references(() => users.id),
|
|
});
|
|
|
|
const heirs = sqliteTable("heirs", {
|
|
id: text("id").primaryKey(),
|
|
userID: text("user_id")
|
|
.notNull()
|
|
.references(() => users.id),
|
|
createdAt: integer("created_at").notNull(),
|
|
name: text("name").notNull(),
|
|
email: text("email"),
|
|
});
|
|
|
|
const musicEntries = sqliteTable("music_entries", {
|
|
id: text("id").primaryKey(),
|
|
artist: text("artist").notNull(),
|
|
title: text("title").notNull(),
|
|
links: text("links").notNull(),
|
|
universalIDs: text("universal_ids").notNull(),
|
|
});
|
|
|
|
const locationEntries = sqliteTable("location_entries", {
|
|
id: text("id").primaryKey(),
|
|
locationText: text("location_text"),
|
|
locationCoordinates: text("location_coordinates"),
|
|
});
|
|
|
|
const dateEntries = sqliteTable("date_entries", {
|
|
id: text("id").primaryKey(),
|
|
referencedDate: integer("referenced_date"),
|
|
});
|
|
|
|
const entries = sqliteTable("entries", {
|
|
id: text("id").primaryKey(),
|
|
userID: text("user_id")
|
|
.notNull()
|
|
.references(() => users.id),
|
|
createdAt: integer("created_at").notNull(),
|
|
feelings: text("feelings").notNull(),
|
|
assets: text("assets").notNull(),
|
|
title: text("title"),
|
|
description: text("description"),
|
|
kind: text("kind").notNull(),
|
|
musicEntry: text("music_entry").references(() => musicEntries.id),
|
|
locationEntry: text("location_entry").references(() => locationEntries.id),
|
|
dateEntry: text("date_entry").references(() => dateEntries.id),
|
|
});
|
|
|
|
await runMigrations(database);
|
|
|
|
let funcs = {
|
|
insertHeir: async (heir: typeof heirs.$inferInsert) => {
|
|
let result = await database.insert(heirs).values(heir).returning({ id: heirs.id });
|
|
return result[0].id;
|
|
},
|
|
removeHeir: async (id: string) => {
|
|
await database.delete(heirs).where(eq(heirs.id, id));
|
|
},
|
|
listHeirs: async (userID: string) => {
|
|
return await database.select().from(heirs).where(eq(heirs.userID, userID));
|
|
},
|
|
insertUser: async (user: typeof users.$inferInsert, limit: typeof limits.$inferInsert) => {
|
|
let limitsResult = await database.insert(limits).values(limit).returning({ id: limits.id });
|
|
user.limitID = limitsResult[0].id;
|
|
|
|
let userResult = await database.insert(users).values(user).returning();
|
|
return userResult[0];
|
|
},
|
|
user: async (userID: string) => {
|
|
let result = await database.select().from(users).where(eq(users.id, userID));
|
|
return result[0];
|
|
},
|
|
userLimits: async (limitsID: string) => {
|
|
let result = await database.select().from(limits).where(eq(limits.id, limitsID));
|
|
return result[0];
|
|
},
|
|
updateUser: async (userID: string, newUser: {
|
|
name?: string,
|
|
email?: string,
|
|
password?: string,
|
|
}) => {
|
|
let result = await database.update(users).set(newUser).where(eq(users.id, userID)).returning();
|
|
return result[0];
|
|
},
|
|
findUserByEmail: async (email: string) => {
|
|
let result = await database.select().from(users).where(eq(users.email, email));
|
|
return result[0];
|
|
},
|
|
insertSessionKey: async (key: typeof session_keys.$inferInsert) => {
|
|
let result = await database.insert(session_keys).values(key).returning({ key: session_keys.key });
|
|
return result[0].key;
|
|
},
|
|
sessionKey: async (key: string) => {
|
|
let result = await database.select().from(session_keys).where(eq(session_keys.key, key));
|
|
return result[0];
|
|
},
|
|
findSessionKeyByUserID: async (userID: string) => {
|
|
return await database.select().from(session_keys).where(eq(session_keys.userID, userID));
|
|
},
|
|
insertEntry: async (entry: typeof entries.$inferInsert, musicEntry?: typeof musicEntries.$inferInsert, locationEntry?: typeof locationEntries.$inferInsert, dateEntry?: typeof dateEntries.$inferInsert) => {
|
|
if (entry.kind === "album" || entry.kind === "song") {
|
|
let result = await database.insert(musicEntries).values(musicEntry).returning({ id: musicEntries.id });
|
|
entry.musicEntry = result[0].id;
|
|
} else if (entry.kind === "environment") {
|
|
let result = await database
|
|
.insert(locationEntries)
|
|
.values(locationEntry)
|
|
.returning({ id: locationEntries.id });
|
|
entry.locationEntry = result[0].id;
|
|
} else if (entry.kind === "date") {
|
|
let result = await database.insert(dateEntries).values(dateEntry).returning({ id: dateEntries.id });
|
|
entry.dateEntry = result[0].id;
|
|
}
|
|
|
|
let result = await database.insert(entries).values(entry).returning({ id: entries.id });
|
|
return result[0].id;
|
|
},
|
|
removeEntry: async (entryID: string) => {
|
|
await database.delete(entries).where(eq(entries.id, entryID));
|
|
},
|
|
entryPage: async (userID: string, offset: number, limit: number) => {
|
|
let result = await database
|
|
.select()
|
|
.from(entries)
|
|
.where(eq(entries.userID, userID))
|
|
.limit(limit)
|
|
.offset(offset)
|
|
.orderBy(desc(entries.createdAt));
|
|
|
|
for (let key in result) {
|
|
if (!result.hasOwnProperty(key)) { continue; }
|
|
|
|
let entry = structuredClone(result[key]);
|
|
let base = {};
|
|
if (entry.musicEntry != null) {
|
|
let musicDetails = (await database.select().from(musicEntries).where(eq(musicEntries.id, entry.musicEntry)))[0];
|
|
(musicDetails["link"] as any) = fromDBList(musicDetails.links);
|
|
(musicDetails["id"] as any) = fromDBList(musicDetails.universalIDs);
|
|
|
|
musicDetails["links"] = undefined;
|
|
musicDetails["universalIDs"] = undefined;
|
|
base = musicDetails;
|
|
} else if (entry.locationEntry != null) {
|
|
let locationDetails = (await database.select().from(locationEntries).where(eq(locationEntries.id, entry.locationEntry)))[0];
|
|
|
|
if (locationDetails.locationCoordinates != null) {
|
|
base = { location: JSON.parse(locationDetails.locationCoordinates) }
|
|
} else if (locationDetails.locationText != null) {
|
|
base = { location: locationDetails.locationText }
|
|
}
|
|
} else if (entry.dateEntry != null) {
|
|
let dateDetails = (await database.select().from(dateEntries).where(eq(dateEntries.id, entry.dateEntry)))[0];
|
|
|
|
base = {
|
|
referencedDate: new Date(dateDetails["referencedDate"]).toISOString()
|
|
};
|
|
}
|
|
|
|
base["kind"] = entry.kind
|
|
|
|
result[key]["creationDate"] = new Date(entry.createdAt).toISOString();
|
|
(result[key] as any)["feelings"] = fromDBList(entry.feelings);
|
|
(result[key] as any)["assets"] = fromDBList(entry.assets);
|
|
result[key]["base"] = base;
|
|
|
|
result[key].kind = undefined;
|
|
result[key].userID = undefined;
|
|
result[key].musicEntry = undefined;
|
|
result[key].locationEntry = undefined;
|
|
result[key].dateEntry = undefined;
|
|
}
|
|
|
|
return result;
|
|
},
|
|
};
|
|
|
|
return funcs;
|
|
}
|
|
|
|
async function runMigrations(database) {
|
|
await database.run(sql`CREATE TABLE IF NOT EXISTS limits (
|
|
id varchar PRIMARY KEY,
|
|
current_asset_count integer NOT NULL,
|
|
max_asset_count integer NOT NULL
|
|
);`);
|
|
|
|
await database.run(sql`CREATE TABLE IF NOT EXISTS users (
|
|
id varchar PRIMARY KEY,
|
|
created_at timestamp NOT NULL,
|
|
last_connected_at timestamp NOT NULL,
|
|
email varchar NOT NULL,
|
|
password varchar NOT NULL,
|
|
name varchar NOT NULL,
|
|
limits varchar NOT NULL,
|
|
assets varchar NOT NULL,
|
|
FOREIGN KEY (limits) REFERENCES limits (id)
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS session_keys (
|
|
key varchar PRIMARY KEY,
|
|
user_id varchar NOT NULL,
|
|
FOREIGN KEY (user_id) REFERENCES users (id)
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS heirs (
|
|
id varchar PRIMARY KEY,
|
|
user_id varchar NOT NULL,
|
|
created_at timestamp NOT NULL,
|
|
name varchar NOT NULL,
|
|
email varchar,
|
|
FOREIGN KEY (user_id) REFERENCES users (id)
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS entries (
|
|
id varchar PRIMARY KEY,
|
|
user_id varchar NOT NULL,
|
|
created_at timestamp NOT NULL,
|
|
feelings text NOT NULL,
|
|
assets text NOT NULL,
|
|
title text,
|
|
description text,
|
|
kind varchar NOT NULL,
|
|
music_entry varchar,
|
|
location_entry varchar,
|
|
date_entry varchar,
|
|
FOREIGN KEY (user_id) REFERENCES users (id),
|
|
FOREIGN KEY (music_entry) REFERENCES music_entries (id),
|
|
FOREIGN KEY (location_entry) REFERENCES location_entries (id),
|
|
FOREIGN KEY (date_entry) REFERENCES date_entries (id)
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS music_entries (
|
|
id varchar PRIMARY KEY,
|
|
artist varchar NOT NULL,
|
|
title varchar NOT NULL,
|
|
links text NOT NULL,
|
|
universal_ids text NOT NULL
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS location_entries (
|
|
id varchar PRIMARY KEY,
|
|
location_text text,
|
|
location_coordinates varchar
|
|
);`);
|
|
|
|
await database.run(sql`
|
|
CREATE TABLE IF NOT EXISTS date_entries (
|
|
id varchar PRIMARY KEY,
|
|
referenced_date timestamp
|
|
);`);
|
|
}
|