what2watch/migrations/20230426221940_init.up.sql

75 lines
2.9 KiB
SQL

-- note: sqlite-specific migration due to the types of the columns
-- When used for an ID, a blob is a UUID in byte form, or a vector of those like for friends list.
-- Otherwise, for content, a blob is just binary data, possibly representing UTF-8 text.
-- Dates are ints, unix epoch style
-- users
create table if not exists witches (
id blob not null primary key,
username text not null unique,
displayname text,
email text,
last_seen int,
pwhash blob not null,
last_updated int not null default (unixepoch())
);
-- table of things to watch
create table if not exists watches (
id blob not null primary key,
kind int not null, -- enum for movie or tv show or whatev
title text not null,
metadata_url text, -- possible url for imdb or other metadata-esque site to show the user
length int,
release_date int,
added_by blob not null, -- ID of the user that added it
last_updated int not null default (unixepoch()),
foreign key (added_by) references witches (id)
);
-- table of what people want to watch
create table if not exists witch_watch (
witch blob not null,
watch blob not null,
party blob, -- list of witch IDs, but we can also scan for friends that want to watch the same thing
priority int, -- 1-5 how much do you want to watch it
public boolean not null,
watched boolean not null,
when_added int,
when_watched int,
last_updated int not null default (unixepoch()),
foreign key (witch) references witches (id) on delete cascade on update no action,
foreign key (watch) references watches (id) on delete cascade on update no action,
primary key (witch, watch)
) without rowid;
-- friend lists; this should really be a graph db, maybe the whole thing should be
-- TODO: look into replacing sqlite with https://www.cozodb.org/
create table if not exists covens (
witch blob not null primary key,
coven blob, -- possibly empty friends list in some app-specific format
last_updated int not null default (unixepoch()),
foreign key (witch) references witches (id) on delete cascade on update no action
);
create table if not exists watch_notes (
id blob not null primary key,
witch blob not null,
watch blob not null,
note blob,
public boolean not null,
last_updated int not null default (unixepoch()),
foreign key (witch) references witches (id) on delete cascade on update no action,
foreign key (watch) references watches (id) on delete cascade on update no action
);
-- indices, not needed for covens
create index if not exists witch_username_dex on witches (username);
create index if not exists witch_email_dex on witches (email);
create index if not exists watch_title_dex on watches (title);
create index if not exists watch_added_by_dex on watches (added_by);
create index if not exists ww_witch_dex on witch_watch (witch);
create index if not exists ww_watch_dex on witch_watch (watch);
create index if not exists note_witch_dex on watch_notes (witch);
create index if not exists note_watch_dex on watch_notes (watch);