feat!: rewritten db scheme

This commit is contained in:
nihonium 2025-10-26 02:09:44 +03:00
parent db53ae04e3
commit 71e2661fb9
Signed by: nihonium
GPG key ID: 0251623741027CFC
2 changed files with 112 additions and 65 deletions

View file

@ -1,7 +1,12 @@
DROP TRIGGER IF EXISTS trg_update_title_rating ON usertitles;
DROP TRIGGER IF EXISTS trg_notify_new_signal ON signals;
DROP FUNCTION IF EXISTS update_title_rating();
DROP FUNCTION IF EXISTS notify_new_signal();
DROP TABLE IF EXISTS signals;
DROP TABLE IF EXISTS title_tags;
DROP TABLE IF EXISTS usertitles;
DROP TABLE IF EXISTS reviews;
DROP TABLE IF EXISTS titles;
DROP TABLE IF EXISTS studios;
DROP TABLE IF EXISTS users;

View file

@ -1,99 +1,141 @@
-- TODO:
-- title table triggers
-- maybe jsonb constraints
-- actions (delete)
-- 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 (
provider_id serial PRIMARY KEY,
provider_name varchar(64) NOT NULL
-- token
id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
provider_name text NOT NULL,
credentials jsonb
);
CREATE TABLE tags (
tag_id serial PRIMARY KEY,
tag_names jsonb NOT NULL --mb constraints
id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
tag_names jsonb NOT NULL
);
-- clean unused images
CREATE TABLE images (
image_id serial PRIMARY KEY,
storage_type storage_type_t NOT NULL,
image_path varchar(256) UNIQUE NOT NULL
id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
storage_type storage_type_t NOT NULL,
image_path text UNIQUE NOT NULL
);
CREATE TABLE users (
user_id serial PRIMARY KEY,
avatar_id int REFERENCES images (image_id),
passhash text NOT NULL,
mail varchar(64) CHECK (mail ~ '[a-zA-Z0-9._-]+@[a-zA-Z0-9._-]+\.[a-zA-Z0-9_-]+'),
nickname varchar(16) NOT NULL CHECK (nickname ~ '^[a-zA-Z0-9_-]+$'),
disp_name varchar(32),
user_desc varchar(512),
-- timestamp tl dr, also add access ts
creation_date timestamp NOT NULL
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 (
studio_id serial PRIMARY KEY,
studio_name varchar(64) UNIQUE,
illust_id int REFERENCES images (image_id),
studio_desc text
id bigint GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
studio_name text UNIQUE,
illust_id int REFERENCES images (id),
studio_desc text
);
CREATE TABLE titles (
title_id serial PRIMARY KEY,
title_names jsonb NOT NULL,
studio_id int NOT NULL REFERENCES studios,
poster_id int REFERENCES images (image_id),
--signal_ids int[] NOT NULL,
title_status title_status_t NOT NULL,
rating float CHECK (rating > 0 AND rating <= 10), --by trigger
rating_count int CHECK (rating_count >= 0), --by trigger
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,
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 reviews (
review_id serial PRIMARY KEY, --???
user_id int NOT NULL REFERENCES users,
title_id int NOT NULL REFERENCES titles,
--image_ids int[], move somewhere
review_text text NOT NULL,
creation_date timestamp NOT NULL
-- constrai (title, user)
);
CREATE TABLE usertitles (
usertitle_id serial PRIMARY KEY, -- bigserial, replace by (,)
user_id int NOT NULL REFERENCES users,
title_id int NOT NULL REFERENCES titles,
status usertitle_status_t NOT NULL,
rate int CHECK (rate > 0 AND rate <= 10),
review_id int REFERENCES reviews
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 int NOT NULL REFERENCES titles,
tag_id int NOT NULL REFERENCES 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 (
signal_id serial PRIMARY KEY,
-- title_id
raw_data jsonb NOT NULL,
provider_id int NOT NULL REFERENCES providers,
dirty bool NOT NULL
);
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();