97 lines
No EOL
3.8 KiB
PL/PgSQL
97 lines
No EOL
3.8 KiB
PL/PgSQL
-- TODO:
|
|
-- title table triggers
|
|
-- maybe jsonb constraints
|
|
-- actions (delete)
|
|
BEGIN;
|
|
|
|
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
|
|
);
|
|
|
|
CREATE TABLE tags (
|
|
tag_id serial PRIMARY KEY,
|
|
tag_names jsonb NOT NULL --mb constraints
|
|
);
|
|
|
|
CREATE TABLE images (
|
|
image_id serial PRIMARY KEY,
|
|
storage_type storage_type_t NOT NULL,
|
|
image_path varchar(256) 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),
|
|
creation_date timestamp NOT NULL
|
|
);
|
|
|
|
CREATE TABLE studios (
|
|
studio_id serial PRIMARY KEY,
|
|
studio_name varchar(64) UNIQUE,
|
|
illust_id int REFERENCES images (image_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,
|
|
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[],
|
|
review_text text NOT NULL,
|
|
creation_date timestamp NOT NULL
|
|
);
|
|
|
|
CREATE TABLE usertitles (
|
|
usertitle_id serial PRIMARY KEY,
|
|
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
|
|
);
|
|
|
|
CREATE TABLE title_tags (
|
|
PRIMARY KEY (title_id, tag_id),
|
|
title_id int NOT NULL REFERENCES titles,
|
|
tag_id int NOT NULL REFERENCES tags
|
|
);
|
|
|
|
CREATE TABLE signals (
|
|
signal_id serial PRIMARY KEY,
|
|
raw_data jsonb NOT NULL,
|
|
provider_id int NOT NULL REFERENCES providers,
|
|
dirty bool NOT NULL
|
|
);
|
|
|
|
COMMIT; |