-- TODO: -- maybe jsonb constraints -- clean unused images CREATE TYPE usertitle_status_t AS ENUM ('finished', 'planned', 'dropped', 'in-progress'); CREATE TYPE storage_type_t AS ENUM ('local', 's3'); CREATE TYPE title_status_t AS ENUM ('finished', 'ongoing', 'planned'); CREATE TYPE release_season_t AS ENUM ('winter', 'spring', 'summer', 'fall'); CREATE TABLE providers ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, provider_name text NOT NULL, credentials jsonb ); CREATE TABLE tags ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, tag_names jsonb NOT NULL ); CREATE TABLE images ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, storage_type storage_type_t NOT NULL, image_path text UNIQUE NOT NULL ); CREATE TABLE users ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, avatar_id int REFERENCES images (id), passhash text NOT NULL, mail text CHECK (mail ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9._-]+\.[a-zA-Z0-9_-]+'), nickname text NOT NULL CHECK (nickname ~ '^[a-zA-Z0-9_-]+$'), disp_name text, user_desc text, creation_date timestamptz NOT NULL, last_login timestamptz ); CREATE TABLE studios ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, studio_name text UNIQUE, illust_id int REFERENCES images (id), studio_desc text ); CREATE TABLE titles ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, title_names jsonb NOT NULL, studio_id bigint NOT NULL REFERENCES studios (id), poster_id bigint REFERENCES images (id), title_status title_status_t NOT NULL, rating float CHECK (rating >= 0 AND rating <= 10), rating_count int CHECK (rating_count >= 0), release_year int CHECK (release_year >= 1900), release_season release_season_t, season int CHECK (season >= 0), episodes_aired int CHECK (episodes_aired >= 0), episodes_all int CHECK (episodes_all >= 0), episodes_len jsonb, CHECK ((episodes_aired IS NULL AND episodes_all IS NULL) OR (episodes_aired IS NOT NULL AND episodes_all IS NOT NULL AND episodes_aired <= episodes_all)) ); CREATE TABLE usertitles ( PRIMARY KEY (user_id, title_id), user_id bigint NOT NULL REFERENCES users (id), title_id bigint NOT NULL REFERENCES titles (id), status usertitle_status_t NOT NULL, rate int CHECK (rate > 0 AND rate <= 10), review_text text, review_date timestamptz ); CREATE TABLE title_tags ( PRIMARY KEY (title_id, tag_id), title_id bigint NOT NULL REFERENCES titles (id), tag_id bigint NOT NULL REFERENCES tags (id) ); CREATE TABLE signals ( id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY, title_id bigint REFERENCES titles (id), raw_data jsonb NOT NULL, provider_id bigint NOT NULL REFERENCES providers (id), pending boolean NOT NULL ); -- Functions CREATE OR REPLACE FUNCTION update_title_rating() RETURNS TRIGGER AS $$ BEGIN IF (TG_OP = 'INSERT') OR (TG_OP = 'UPDATE' AND NEW.rate IS DISTINCT FROM OLD.rate) THEN UPDATE titles SET rating = sub.avg_rating, rating_count = sub.rating_count FROM ( SELECT title_id, AVG(rate)::float AS avg_rating, COUNT(rate) AS rating_count FROM usertitles WHERE title_id = NEW.title_id AND rate IS NOT NULL GROUP BY title_id ) AS sub WHERE titles.id = sub.title_id; END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION notify_new_signal() RETURNS TRIGGER AS $$ DECLARE payload JSON; BEGIN payload := json_build_object( 'signal_id', NEW.id, 'title_id', NEW.title_id, 'provider_id', NEW.provider_id, 'pending', NEW.pending, 'timestamp', NOW() ); PERFORM pg_notify('new_signal', payload::text); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Triggers CREATE TRIGGER trg_update_title_rating AFTER INSERT OR UPDATE OF rate ON usertitles FOR EACH ROW EXECUTE FUNCTION update_title_rating(); CREATE TRIGGER trg_notify_new_signal AFTER INSERT ON signals FOR EACH ROW EXECUTE FUNCTION notify_new_signal();