-- 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 date, added_by blob not null, -- ID of the user that added it last_updated datetime not null default CURRENT_TIMESTAMP, foreign key (added_by) references users (id) ); create index if not exists watches_title_dex on watches (lower(title)); create trigger if not exists update_last_updated_watches after update on watches when OLD.last_updated = NEW.last_updated or OLD.last_updated is null BEGIN update watches set last_updated = CURRENT_TIMESTAMP where id=NEW.id; END; -- 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 datetime, created_at datetime not null default CURRENT_TIMESTAMP, last_updated datetime not null default CURRENT_TIMESTAMP, 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 trigger if not exists update_last_updated_watch_quests after update on watch_quests when OLD.last_updated = NEW.last_updated or OLD.last_updated is null BEGIN update watch_quests set last_updated = CURRENT_TIMESTAMP where watch=NEW.watch and user=NEW.user; END; -- notes on stuff to watch 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 datetime not null default CURRENT_TIMESTAMP, 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); create trigger if not exists update_last_updated_watch_notes after update on watch_notes when OLD.last_updated = NEW.last_updated or OLD.last_updated is null BEGIN update watch_notes set last_updated = CURRENT_TIMESTAMP where id=NEW.id; END;