-- 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 users ( id blob not null primary key default (julid_new()), username text not null unique, displayname text, email text, last_seen int, pwhash blob not null, invited_by blob not null, is_active int not null default 1, last_updated int not null default (unixepoch()), foreign key (invited_by) references users (id) ); create index if not exists users_username_dex on users (lower(username)); create index if not exists users_email_dex on users (lower(email)); create index if not exists users_invited_by_dex on users (invited_by); -- invitations create table if not exists invites ( id blob not null primary key default (julid_new()), owner blob not null, expires_at int, remaining int not null default 1, last_updated int not null default (unixepoch()), foreign key (owner) references users (id) on delete cascade on update no action ); create index if not exists invites_owner_dex on invites (owner); -- table of things to watch create table if not exists watches ( id blob not null primary key default (julid_new()), 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 users (id) ); create index if not exists watches_title_dex on watches (lower(title)); -- table of what people want to watch create table if not exists watch_quests ( user blob not null, watch blob not null, priority int, -- 1-5 how much do you want to watch it public boolean not null default true, watched boolean not null default false, when_watched int, created_at int not null default (unixepoch()), last_updated int not null default (unixepoch()), foreign key (user) references users (id) on delete cascade on update no action, foreign key (watch) references watches (id) on delete cascade on update no action, primary key (user, watch) ); create index if not exists quests_user_dex on watch_quests (user); create index if not exists quests_watch_dex on watch_quests (watch); create table if not exists follows ( follower blob not null, followee blob not null, created_at int not null default (unixepoch()), foreign key (follower) references users (id) on delete cascade on update no action foreign key (followee) references users (id) on delete cascade on update no action ); create index if not exists follows_follower_dex on follows (follower); create index if not exists follows_followee_dex on follows (followee); create table if not exists watch_notes ( id blob not null primary key default (julid_new()), -- a user can have multiple notes about the same thing user blob not null, watch blob not null, note blob, public boolean not null, last_updated int not null default (unixepoch()), foreign key (user) references users (id) on delete cascade on update no action, foreign key (watch) references watches (id) on delete cascade on update no action ); create index if not exists notes_user_dex on watch_notes (user); create index if not exists notes_watch_dex on watch_notes (watch); -- indices