import { createNote, createUser, initDatabaseConnectionPool, queryArray, } from "@/db/mod.ts"; import { reload } from "@/config.ts"; import { log, setupLoggers } from "@/log.ts"; const [config, configLoadLogCallbacks] = reload(); setupLoggers(config.log); for (const f of configLoadLogCallbacks) { f(log); } initDatabaseConnectionPool(config.postgres); const id = "id uuid primary key default generate_ulid()"; interface TableSpec { columns: string[]; additionalTableStatements?: string[]; additionalStatements?: string[]; prepStatements?: string[]; } const createdAtTimestamp = "created_at timestamptz not null default now()"; const updatedAtTimestamp = "updated_at timestamptz not null default now()"; const timestamps = [createdAtTimestamp, updatedAtTimestamp]; const extensions = [ "uuid-ossp", "pgcrypto", ]; const functions = [ ` create or replace function generate_ulid() returns uuid as $$ select (lpad(to_hex(floor(extract(epoch from clock_timestamp()) * 1000)::bigint), 12, '0') || encode(gen_random_bytes(10), 'hex'))::uuid; $$ language sql `, ]; const tables: Record = { "user": { columns: [ id, "username text not null unique", "password_digest text not null", "display_name text", ...timestamps, ], additionalTableStatements: [ "constraint valid_username check (username ~* '^[a-z\\d\\-_]{2,38}$')", ], }, "token": { columns: [ "digest bytea not null unique", "user_id uuid not null", "data jsonb", createdAtTimestamp, ], additionalStatements: [ "create index team_data_type on token using hash ((data->'type'))", ], additionalTableStatements: [ 'constraint fk_user foreign key(user_id) references "user"(id) on delete cascade', ], }, "team": { columns: [ id, "display_name text not null", ...timestamps, ], additionalStatements: [ 'create index display_name_idx on team ("display_name")', ], }, "team_user": { prepStatements: [ "drop type if exists team_user_status", "create type team_user_status as enum ('invited', 'accepted', 'manager', 'owner', 'removed', 'left')", ], columns: [ "team_id uuid", "user_id uuid", "status team_user_status not null", ...timestamps, ], additionalTableStatements: [ 'constraint fk_team foreign key(team_id) references "team"(id) on delete cascade', 'constraint fk_user foreign key(user_id) references "user"(id) on delete cascade', ], additionalStatements: [ "create index team_user_idx on team_user (team_id) include (user_id)", "create index team_idx on team_user (team_id)", "create index user_idx on team_user (user_id)", "create index status_idx on team_user (status)", ], }, "note": { columns: [ id, "user_id uuid default null", "content text not null", ...timestamps, ], additionalTableStatements: [ 'constraint fk_user foreign key(user_id) references "user"(id) on delete cascade', ], }, "playlist": { columns: [ id, "display_name text not null", "team_id uuid not null", ...timestamps, ], additionalTableStatements: [ 'constraint fk_team foreign key(team_id) references "team"(id) on delete cascade', ], }, "display": { columns: [ id, "display_name text default null", "team_id uuid not null", "is_frozen boolean default false", "is_blanked boolean default false", "playlist_id uuid not null", "current_song_index integer default 0", "current_verse_index integer default 0", ...timestamps, ], additionalTableStatements: [ // TODO: index timestamps? 'constraint fk_playlist foreign key(playlist_id) references "playlist"(id) on delete cascade', ], }, "song": { columns: [ id, "team_id uuid not null", ...timestamps, ], additionalTableStatements: [ // TODO: index timestamps? 'constraint fk_team foreign key(team_id) references "team"(id) on delete cascade', ], }, "verse": { columns: [ id, "display_name text default null", "content text not null default ''", "song_id uuid not null", ...timestamps, ], additionalTableStatements: [ 'constraint fk_song foreign key(song_id) references "song"(id) on delete cascade', ], }, "map": { columns: [ id, "display_name text not null", "song_id uuid not null", ...timestamps, ], additionalTableStatements: [ 'constraint fk_song foreign key(song_id) references "song"(id) on delete cascade', ], }, "map_verse": { columns: [ "map_id uuid", "verse_id uuid", '"index" integer not null', ...timestamps, ], additionalTableStatements: [ // TODO: is there a way to enforce that both of these must have the same song_id? 'constraint fk_map foreign key(map_id) references "map"(id) on delete cascade', 'constraint fk_song foreign key(verse_id) references "verse"(id) on delete cascade', ], additionalStatements: [ 'create index map_verse_idx on "map_verse" (map_id) include (verse_id)', 'create index map_idx on "map_verse" (map_id)', 'create index verse_idx on "map_verse" (verse_id)', 'create unique index map_index_idx on "map_verse" (map_id) include ("index")', ], }, "playlist_song": { columns: [ "playlist_id uuid", "song_id uuid", "map_id uuid", '"index" integer not null', ...timestamps, ], additionalTableStatements: [ // TODO: is there a way to enforce that playlist and song have the same team_id? // TODO: is there a way to enforce that map.song_id is the same as song.id? // TODO: if the map is deleted, do we really want to cascade it across playlists? 'constraint fk_playlist foreign key(playlist_id) references "playlist"(id) on delete cascade', 'constraint fk_song foreign key(song_id) references "song"(id) on delete cascade', 'constraint fk_map foreign key(map_id) references "map"(id) on delete cascade', ], additionalStatements: [ 'create index playlist_song_idx on "playlist_song" (playlist_id) include (song_id)', 'create index playlist_idx on "playlist_song" (playlist_id)', 'create index song_idx on "playlist_song" (song_id)', 'create unique index playlist_index_idx on "playlist_song" (playlist_id) include ("index")', ], }, }; const createExtensions = extensions.map((s) => `create extension if not exists "${s.trim()}";` ).join("\n"); const createFunctions = functions.map((s) => s.trim() + ";").join("\n"); const dropTables = Object.entries(tables).reverse().map(([name, _meta]) => `drop table if exists "${name.trim()}";` ).join("\n"); const createTables = Object.entries(tables).map(([rawName, meta]) => { const name = rawName.trim(); return ` -- CREATE TABLE ${name} ${(meta.prepStatements || []).map((s) => `${s.trim()};`).join("\n")} create table "${name}" ( ${ meta.columns.concat(meta.additionalTableStatements || []).map((s) => s.trim() ).join(",\n ") } ); ${(meta.additionalStatements || []).map((s) => `${s.trim()};`).join("\n")} `; }).map((s) => s.trim()).join("\n\n"); const cleanupQuery = ` begin; ${dropTables} commit; `; console.log(cleanupQuery); try { const setupResult = await queryArray(cleanupQuery); console.debug(setupResult); } catch (err) { console.log("Failed to run migration cleanup query:", { ...err }); throw err; } const queryString = ` ${createExtensions} ${createFunctions} ${createTables} commit; `; console.log(queryString); try { const setupResult = await queryArray(queryString); console.debug(setupResult); } catch (err) { console.log("Failed to run migration setup query:", { ...err }); throw err; } try { const [note, user] = await Promise.all([ createNote({ userId: null, content: "Hello, notes!" }), createUser({ username: "lytedev", passwordDigest: "$2a$10$9fyDAOz6H4a393KHyjbvIe1WFxbhCJhq/CZmlXcEg4d1bE9Ey25WW", }), ]); console.debug({ note, user }); } catch (err) { console.log("Failed to run seed database:", { ...err }); throw err; }