mirror of
https://github.com/Arcadia-Solutions/arcadia.git
synced 2025-12-16 23:14:15 -06:00
1269 lines
44 KiB
PL/PgSQL
1269 lines
44 KiB
PL/PgSQL
CREATE TYPE user_permissions_enum AS ENUM (
|
|
'create_user_class',
|
|
'edit_user_class',
|
|
'delete_user_class',
|
|
'edit_user_permissions',
|
|
'change_user_class',
|
|
'lock_user_class',
|
|
'upload_torrent',
|
|
'download_torrent',
|
|
'create_torrent_request',
|
|
'immune_activity_pruning',
|
|
'edit_title_group',
|
|
'edit_title_group_comment',
|
|
'edit_edition_group',
|
|
'edit_torrent',
|
|
'edit_artist',
|
|
'edit_collage',
|
|
'edit_series',
|
|
'edit_torrent_request',
|
|
'edit_forum_post',
|
|
'edit_forum_thread',
|
|
'edit_forum_sub_category',
|
|
'edit_forum_category',
|
|
'create_forum_category',
|
|
'create_forum_sub_category',
|
|
'create_forum_thread',
|
|
'create_forum_post',
|
|
'send_pm',
|
|
'create_css_sheet',
|
|
'edit_css_sheet',
|
|
'set_default_css_sheet',
|
|
'read_staff_pm',
|
|
'reply_staff_pm',
|
|
'resolve_staff_pm',
|
|
'unresolve_staff_pm',
|
|
'delete_title_group_tag',
|
|
'edit_title_group_tag',
|
|
'delete_torrent',
|
|
'get_user_application',
|
|
'update_user_application',
|
|
'warn_user',
|
|
'edit_user',
|
|
'create_wiki_article',
|
|
'edit_wiki_article',
|
|
'edit_arcadia_settings'
|
|
);
|
|
CREATE TABLE user_classes (
|
|
name VARCHAR(30) UNIQUE NOT NULL,
|
|
default_permissions user_permissions_enum[] NOT NULL DEFAULT '{}'
|
|
);
|
|
INSERT INTO user_classes (name, default_permissions)
|
|
VALUES ('newbie', '{}');
|
|
CREATE TABLE users (
|
|
id SERIAL PRIMARY KEY,
|
|
username VARCHAR(15) UNIQUE NOT NULL,
|
|
avatar TEXT,
|
|
email VARCHAR(255) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
registered_from_ip INET NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
description TEXT NOT NULL DEFAULT '',
|
|
uploaded BIGINT NOT NULL DEFAULT 0,
|
|
real_uploaded BIGINT NOT NULL DEFAULT 0,
|
|
-- 1 byte downloaded
|
|
downloaded BIGINT NOT NULL DEFAULT 1,
|
|
real_downloaded BIGINT NOT NULL DEFAULT 1,
|
|
ratio FLOAT NOT NULL DEFAULT 0.0,
|
|
required_ratio FLOAT NOT NULL DEFAULT 0.0,
|
|
last_seen TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
class_name VARCHAR(30) NOT NULL REFERENCES user_classes(name) ON UPDATE CASCADE,
|
|
class_locked BOOLEAN NOT NULL DEFAULT FALSE,
|
|
permissions user_permissions_enum[] NOT NULL DEFAULT '{}',
|
|
forum_posts INTEGER NOT NULL DEFAULT 0,
|
|
forum_threads INTEGER NOT NULL DEFAULT 0,
|
|
torrent_comments INTEGER NOT NULL DEFAULT 0,
|
|
request_comments INTEGER NOT NULL DEFAULT 0,
|
|
artist_comments BIGINT NOT NULL DEFAULT 0,
|
|
seeding INTEGER NOT NULL DEFAULT 0,
|
|
leeching INTEGER NOT NULL DEFAULT 0,
|
|
snatched INTEGER NOT NULL DEFAULT 0,
|
|
seeding_size BIGINT NOT NULL DEFAULT 0,
|
|
requests_filled BIGINT NOT NULL DEFAULT 0,
|
|
collages_started BIGINT NOT NULL DEFAULT 0,
|
|
requests_voted BIGINT NOT NULL DEFAULT 0,
|
|
average_seeding_time BIGINT NOT NULL DEFAULT 0,
|
|
invited BIGINT NOT NULL DEFAULT 0,
|
|
invitations SMALLINT NOT NULL DEFAULT 0,
|
|
bonus_points BIGINT NOT NULL DEFAULT 0,
|
|
freeleech_tokens INT NOT NULL DEFAULT 0,
|
|
passkey VARCHAR(32) NOT NULL,
|
|
warned BOOLEAN NOT NULL DEFAULT FALSE,
|
|
banned BOOLEAN NOT NULL DEFAULT FALSE,
|
|
staff_note TEXT NOT NULL DEFAULT '',
|
|
css_sheet_name VARCHAR(30) NOT NULL,
|
|
|
|
UNIQUE(passkey)
|
|
);
|
|
INSERT INTO users (username, email, password_hash, registered_from_ip, passkey, class_name, css_sheet_name)
|
|
VALUES ('creator', 'none@domain.com', 'none', '127.0.0.1', 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa', 'newbie', 'arcadia');
|
|
CREATE TABLE css_sheets (
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL REFERENCES users(id),
|
|
name VARCHAR(30) UNIQUE NOT NULL,
|
|
css TEXT NOT NULL,
|
|
preview_image_url TEXT NOT NULL
|
|
);
|
|
INSERT INTO css_sheets (created_by_id, name, css, preview_image_url)
|
|
VALUES (1, 'arcadia', '', 'https://i.ibb.co/PvSfw9xz/Screenshot-2025-12-06-at-19-53-38-Home-Arcadia-Vault.png');
|
|
-- this needs to be done after the creation of css_sheets and users table
|
|
-- otherwise one of them isn't created yet
|
|
ALTER TABLE users
|
|
ADD CONSTRAINT fk_users_css_sheet
|
|
FOREIGN KEY (css_sheet_name)
|
|
REFERENCES css_sheets(name)
|
|
ON UPDATE CASCADE;
|
|
CREATE TABLE arcadia_settings (
|
|
user_class_name_on_signup VARCHAR(30) NOT NULL REFERENCES user_classes(name) ON UPDATE CASCADE,
|
|
default_css_sheet_name VARCHAR(30) NOT NULL REFERENCES css_sheets(name) ON UPDATE CASCADE,
|
|
open_signups BOOLEAN NOT NULL
|
|
);
|
|
INSERT INTO arcadia_settings (user_class_name_on_signup, default_css_sheet_name, open_signups)
|
|
VALUES ('newbie', 'arcadia', TRUE);
|
|
CREATE TABLE api_keys (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
name VARCHAR(30) NOT NULL,
|
|
value VARCHAR(40) NOT NULL UNIQUE,
|
|
user_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TYPE user_application_status_enum AS ENUM (
|
|
'pending',
|
|
'accepted',
|
|
'rejected'
|
|
);
|
|
CREATE TABLE user_applications (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
body TEXT NOT NULL,
|
|
referral TEXT NOT NULL,
|
|
email TEXT NOT NULL,
|
|
applied_from_ip INET NOT NULL,
|
|
staff_note TEXT NOT NULL DEFAULT '',
|
|
status user_application_status_enum NOT NULL DEFAULT 'pending'
|
|
);
|
|
CREATE TABLE invitations (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
invitation_key VARCHAR(50) NOT NULL,
|
|
message TEXT NOT NULL,
|
|
sender_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
receiver_email VARCHAR(255) NOT NULL,
|
|
user_application_id BIGINT REFERENCES user_applications(id) ON DELETE SET NULL,
|
|
receiver_id INT REFERENCES users(id) ON DELETE SET NULL
|
|
);
|
|
|
|
CREATE TABLE user_warnings (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
expires_at TIMESTAMP WITH TIME ZONE,
|
|
reason TEXT NOT NULL,
|
|
ban boolean NOT NULL,
|
|
created_by_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE gifts (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
sent_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
message TEXT NOT NULL,
|
|
sender_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
receiver_id INT NOT NULL REFERENCES users(id) ON DELETE SET NULL,
|
|
bonus_points BIGINT NOT NULL DEFAULT 0,
|
|
freeleech_tokens INT NOT NULL DEFAULT 0
|
|
);
|
|
CREATE TABLE artists (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(255) UNIQUE NOT NULL,
|
|
description TEXT NOT NULL,
|
|
pictures TEXT [] NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
title_groups_amount INT NOT NULL DEFAULT 0,
|
|
edition_groups_amount INT NOT NULL DEFAULT 0,
|
|
torrents_amount INT NOT NULL DEFAULT 0,
|
|
seeders_amount INT NOT NULL DEFAULT 0,
|
|
leechers_amount INT NOT NULL DEFAULT 0,
|
|
snatches_amount INT NOT NULL DEFAULT 0,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE similar_artists (
|
|
artist_1_id BIGINT NOT NULL,
|
|
artist_2_id BIGINT NOT NULL,
|
|
PRIMARY KEY (artist_1_id, artist_2_id),
|
|
FOREIGN KEY (artist_1_id) REFERENCES artists(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (artist_2_id) REFERENCES artists(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE master_groups (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(255),
|
|
-- name_aliases VARCHAR(255)[],
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
-- description TEXT NOT NULL,
|
|
-- original_language VARCHAR(50) NOT NULL,
|
|
-- country_from VARCHAR(50) NOT NULL,
|
|
-- tags VARCHAR(50)[] NOT NULL,
|
|
-- category VARCHAR(25), -- should only be used for TV-Shows (scripted, reality-tv, etc.)
|
|
-- covers TEXT[],
|
|
-- banners TEXT[],
|
|
-- fan_arts TEXT[],
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE
|
|
SET NULL
|
|
);
|
|
CREATE TABLE similar_master_groups (
|
|
group_1_id INT NOT NULL,
|
|
group_2_id INT NOT NULL,
|
|
PRIMARY KEY (group_1_id, group_2_id),
|
|
FOREIGN KEY (group_1_id) REFERENCES master_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (group_2_id) REFERENCES master_groups(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE series (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT NOT NULL,
|
|
tags TEXT [] NOT NULL,
|
|
covers TEXT [] NOT NULL,
|
|
banners TEXT [] NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TYPE content_type_enum AS ENUM (
|
|
'movie',
|
|
'video',
|
|
'tv_show',
|
|
'music',
|
|
'podcast',
|
|
'software',
|
|
'book',
|
|
'collection'
|
|
);
|
|
CREATE TYPE title_group_category_enum AS ENUM (
|
|
'Ep',
|
|
'Album',
|
|
'Single',
|
|
'Soundtrack',
|
|
'Anthology',
|
|
'Compilation',
|
|
'Remix',
|
|
'Bootleg',
|
|
'Mixtape',
|
|
'ConcertRecording',
|
|
'DjMix',
|
|
'FeatureFilm',
|
|
'ShortFilm',
|
|
'Game',
|
|
'Program',
|
|
'Illustrated',
|
|
'Periodical',
|
|
'Book',
|
|
'Article',
|
|
'Manual',
|
|
'Other'
|
|
);
|
|
CREATE TYPE platform_enum AS ENUM(
|
|
'Linux',
|
|
'MacOS',
|
|
'Windows',
|
|
'Xbox'
|
|
);
|
|
CREATE TYPE language_enum AS ENUM(
|
|
'Albanian',
|
|
'Arabic',
|
|
'Belarusian',
|
|
'Bengali',
|
|
'Bosnian',
|
|
'Bulgarian',
|
|
'Cantonese',
|
|
'Catalan',
|
|
'Chinese',
|
|
'Croatian',
|
|
'Czech',
|
|
'Danish',
|
|
'Dutch',
|
|
'English',
|
|
'Estonian',
|
|
'Finnish',
|
|
'French',
|
|
'German',
|
|
'Greek',
|
|
'Hebrew',
|
|
'Hindi',
|
|
'Hungarian',
|
|
'Icelandic',
|
|
'Indonesian',
|
|
'Italian',
|
|
'Japanese',
|
|
'Kannada',
|
|
'Korean',
|
|
'Macedonian',
|
|
'Malayalam',
|
|
'Mandarin',
|
|
'Nepali',
|
|
'Norwegian',
|
|
'Persian',
|
|
'Polish',
|
|
'Portuguese',
|
|
'Romanian',
|
|
'Russian',
|
|
'Serbian',
|
|
'Spanish',
|
|
'Swedish',
|
|
'Tamil',
|
|
'Tagalog',
|
|
'Telugu',
|
|
'Thai',
|
|
'Turkish',
|
|
'Ukrainian',
|
|
'Vietnamese',
|
|
'Wolof',
|
|
'Other'
|
|
);
|
|
CREATE TABLE title_groups (
|
|
id SERIAL PRIMARY KEY,
|
|
master_group_id INT,
|
|
name TEXT NOT NULL,
|
|
name_aliases TEXT [],
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
description TEXT NOT NULL,
|
|
platform platform_enum,
|
|
original_language language_enum,
|
|
original_release_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
tagline TEXT,
|
|
country_from TEXT,
|
|
covers TEXT [] NOT NULL,
|
|
external_links TEXT [] NOT NULL,
|
|
embedded_links JSONB NOT NULL,
|
|
category title_group_category_enum,
|
|
content_type content_type_enum NOT NULL,
|
|
public_ratings JSONB NOT NULL,
|
|
screenshots TEXT[] NOT NULL,
|
|
series_id BIGINT,
|
|
FOREIGN KEY (master_group_id) REFERENCES master_groups(id) ON DELETE
|
|
SET NULL,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE
|
|
SET NULL,
|
|
FOREIGN KEY (series_id) REFERENCES series(id) ON DELETE
|
|
SET NULL
|
|
);
|
|
CREATE TABLE similar_title_groups (
|
|
group_1_id INT NOT NULL,
|
|
group_2_id INT NOT NULL,
|
|
PRIMARY KEY (group_1_id, group_2_id),
|
|
FOREIGN KEY (group_1_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (group_2_id) REFERENCES title_groups(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE title_group_tags (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(40) NOT NULL,
|
|
synonyms VARCHAR(40)[] DEFAULT '{}',
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
UNIQUE (name)
|
|
);
|
|
|
|
CREATE OR REPLACE FUNCTION enforce_unique_title_group_tag_synonyms()
|
|
RETURNS TRIGGER AS $$
|
|
DECLARE
|
|
existing VARCHAR(40);
|
|
conflict_tag_name VARCHAR(40);
|
|
BEGIN
|
|
-- Loop through each synonym in the new row
|
|
FOREACH existing IN ARRAY NEW.synonyms LOOP
|
|
-- Check if this synonym exists in any other row (or if it's an existing tag name)
|
|
SELECT name INTO conflict_tag_name
|
|
FROM title_group_tags
|
|
WHERE id <> NEW.id
|
|
AND (existing = ANY(synonyms) OR existing = name)
|
|
LIMIT 1;
|
|
|
|
IF conflict_tag_name IS NOT NULL THEN
|
|
RAISE EXCEPTION 'Synonym "%" already exists in title_group_tag "%" ', existing, conflict_tag_name;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER trg_unique_synonyms
|
|
BEFORE INSERT OR UPDATE ON title_group_tags
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION enforce_unique_title_group_tag_synonyms();
|
|
|
|
CREATE TABLE title_group_applied_tags (
|
|
title_group_id INT NOT NULL,
|
|
tag_id INT NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
PRIMARY KEY (title_group_id, tag_id),
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (tag_id) REFERENCES title_group_tags(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TYPE artist_role_enum AS ENUM (
|
|
'main',
|
|
'guest',
|
|
'producer',
|
|
'director',
|
|
'cinematographer',
|
|
'actor',
|
|
'writer',
|
|
'composer',
|
|
'remixer',
|
|
'conductor',
|
|
'dj_compiler',
|
|
'arranger',
|
|
'host',
|
|
'author',
|
|
'illustrator',
|
|
'editor',
|
|
'developer',
|
|
'designer'
|
|
);
|
|
CREATE TABLE affiliated_artists (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title_group_id INT NOT NULL,
|
|
artist_id BIGINT NOT NULL,
|
|
roles artist_role_enum[] NOT NULL,
|
|
nickname VARCHAR(255),
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (artist_id) REFERENCES artists(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE
|
|
SET NULL
|
|
);
|
|
-- for web: if it is a DL or a RIP should be specified at the torrent level
|
|
CREATE TYPE source_enum AS ENUM (
|
|
'CD',
|
|
'DVD5',
|
|
'DVD9',
|
|
'Vinyl',
|
|
'Web',
|
|
'Soundboard',
|
|
'SACD',
|
|
'DAT',
|
|
'Cassette',
|
|
'Blu-Ray',
|
|
'LaserDisc',
|
|
'HD-DVD',
|
|
'HDTV',
|
|
'PDTV',
|
|
'TV',
|
|
'VHS',
|
|
'Mixed',
|
|
'Physical Book'
|
|
);
|
|
CREATE TABLE edition_groups (
|
|
id SERIAL PRIMARY KEY,
|
|
title_group_id INT NOT NULL,
|
|
name TEXT,
|
|
release_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
description TEXT,
|
|
distributor VARCHAR(255),
|
|
covers TEXT [] NOT NULL,
|
|
external_links TEXT [] NOT NULL,
|
|
source source_enum,
|
|
additional_information JSONB,
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE
|
|
SET NULL
|
|
);
|
|
CREATE TYPE audio_codec_enum AS ENUM (
|
|
'mp2',
|
|
'mp3',
|
|
'aac',
|
|
'ac3',
|
|
'dts',
|
|
'flac',
|
|
'pcm',
|
|
'true-hd',
|
|
'opus',
|
|
'dsd'
|
|
);
|
|
|
|
CREATE TYPE video_resolution_enum AS ENUM (
|
|
'Other',
|
|
'480p',
|
|
'480i',
|
|
'576p',
|
|
'576i',
|
|
'720p',
|
|
'1080p',
|
|
'1080i',
|
|
'1440p',
|
|
'2160p',
|
|
'4320p'
|
|
);
|
|
|
|
CREATE TYPE audio_bitrate_sampling_enum AS ENUM(
|
|
'64',
|
|
'128',
|
|
'192',
|
|
'256',
|
|
'320',
|
|
'APS (VBR)',
|
|
'V2 (VBR)',
|
|
'V1 (VBR)',
|
|
'APX (VBR)',
|
|
'V0 (VBR)',
|
|
'Lossless',
|
|
'24bit Lossless',
|
|
'DSD64',
|
|
'DSD128',
|
|
'DSD256',
|
|
'DSD512',
|
|
'other'
|
|
);
|
|
CREATE TYPE audio_channels_enum AS ENUM (
|
|
'1.0',
|
|
'2.0',
|
|
'2.1',
|
|
'5.0',
|
|
'5.1',
|
|
'7.1'
|
|
);
|
|
CREATE TYPE video_codec_enum AS ENUM(
|
|
'mpeg1',
|
|
'mpeg2',
|
|
'Xvid',
|
|
'divX',
|
|
'h264',
|
|
'h265',
|
|
'vc-1',
|
|
'vp9',
|
|
'BD50',
|
|
'UHD100'
|
|
);
|
|
CREATE TYPE features_enum AS ENUM('HDR', 'HDR 10', 'HDR 10+', 'DV', 'Commentary', 'Remux', '3D', 'Cue', 'OCR');
|
|
CREATE TYPE extras_enum AS ENUM('booklet', 'manual', 'behind_the_scenes', 'deleted_scenes', 'featurette', 'trailer', 'other');
|
|
CREATE TABLE torrents (
|
|
id SERIAL PRIMARY KEY,
|
|
upload_factor SMALLINT NOT NULL DEFAULT 100,
|
|
download_factor SMALLINT NOT NULL DEFAULT 100,
|
|
seeders BIGINT NOT NULL DEFAULT 0,
|
|
leechers BIGINT NOT NULL DEFAULT 0,
|
|
times_completed INT NOT NULL DEFAULT 0,
|
|
snatched BIGINT NOT NULL DEFAULT 0,
|
|
edition_group_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
deleted_at TIMESTAMP WITH TIME ZONE DEFAULT NULL,
|
|
deleted_by_id INT DEFAULT NULL,
|
|
info_hash BYTEA NOT NULL CHECK(octet_length(info_hash) = 20),
|
|
info_dict BYTEA NOT NULL,
|
|
languages language_enum[] NOT NULL DEFAULT ARRAY[]::language_enum[],
|
|
release_name TEXT NOT NULL,
|
|
-- maybe change the size
|
|
release_group VARCHAR(30),
|
|
description TEXT,
|
|
file_amount_per_type JSONB NOT NULL,
|
|
uploaded_as_anonymous BOOLEAN NOT NULL DEFAULT FALSE,
|
|
upload_method VARCHAR(50) NOT NULL DEFAULT 'manual',
|
|
file_list JSONB NOT NULL,
|
|
-- maybe change the size to the max length of a file name in a torrent
|
|
mediainfo TEXT,
|
|
trumpable TEXT,
|
|
staff_checked BOOLEAN NOT NULL DEFAULT FALSE,
|
|
container VARCHAR(8) NOT NULL,
|
|
-- in bytes
|
|
size BIGINT NOT NULL,
|
|
|
|
-- audio
|
|
duration INT,
|
|
-- in seconds
|
|
audio_codec audio_codec_enum,
|
|
audio_bitrate INT,
|
|
-- in kb/s, taken from mediainfo
|
|
audio_bitrate_sampling audio_bitrate_sampling_enum,
|
|
audio_channels audio_channels_enum,
|
|
-- audio
|
|
|
|
-- video
|
|
video_codec video_codec_enum,
|
|
features features_enum [] NOT NULL DEFAULT ARRAY[]::features_enum[],
|
|
subtitle_languages language_enum[] NOT NULL DEFAULT ARRAY[]::language_enum[],
|
|
video_resolution video_resolution_enum,
|
|
video_resolution_other_x INT,
|
|
video_resolution_other_y INT,
|
|
|
|
extras extras_enum[] DEFAULT ARRAY[]::extras_enum[],
|
|
|
|
FOREIGN KEY (edition_group_id) REFERENCES edition_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE SET NULL,
|
|
UNIQUE (info_hash)
|
|
);
|
|
CREATE TABLE title_group_comments (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
content TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
title_group_id INT NOT NULL,
|
|
locked BOOLEAN NOT NULL DEFAULT FALSE,
|
|
refers_to_torrent_id INT,
|
|
answers_to_comment_id BIGINT,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (refers_to_torrent_id) REFERENCES torrents(id) ON DELETE SET NULL,
|
|
FOREIGN KEY (answers_to_comment_id) REFERENCES title_group_comments(id) ON DELETE SET NULL
|
|
);
|
|
CREATE TABLE torrent_requests (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title_group_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
filled_by_user_id INT,
|
|
filled_by_torrent_id INT,
|
|
filled_at TIMESTAMP WITH TIME ZONE,
|
|
edition_name TEXT,
|
|
source source_enum[] NOT NULL DEFAULT ARRAY[]::source_enum[],
|
|
release_group VARCHAR(20),
|
|
description TEXT,
|
|
languages language_enum[] NOT NULL DEFAULT ARRAY[]::language_enum[],
|
|
container VARCHAR(8)[] NOT NULL DEFAULT ARRAY[]::VARCHAR(8)[],
|
|
-- Audio
|
|
audio_codec audio_codec_enum[] NOT NULL DEFAULT ARRAY[]::audio_codec_enum[],
|
|
audio_channels audio_channels_enum[] NOT NULL DEFAULT ARRAY[]::audio_channels_enum[],
|
|
audio_bitrate_sampling audio_bitrate_sampling_enum[] NOT NULL DEFAULT ARRAY[]::audio_bitrate_sampling_enum[],
|
|
-- Video
|
|
video_codec video_codec_enum[] NOT NULL DEFAULT ARRAY[]::video_codec_enum[],
|
|
features features_enum[] NOT NULL DEFAULT ARRAY[]::features_enum[],
|
|
subtitle_languages language_enum[] NOT NULL DEFAULT ARRAY[]::language_enum[],
|
|
video_resolution video_resolution_enum[] NOT NULL DEFAULT ARRAY[]::video_resolution_enum[],
|
|
video_resolution_other_x INT,
|
|
video_resolution_other_y INT,
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id),
|
|
FOREIGN KEY (filled_by_user_id) REFERENCES users(id),
|
|
FOREIGN KEY (filled_by_torrent_id) REFERENCES torrents(id)
|
|
);
|
|
CREATE TABLE torrent_request_votes(
|
|
id BIGSERIAL PRIMARY KEY,
|
|
torrent_request_id BIGINT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
bounty_upload BIGINT NOT NULL DEFAULT 0,
|
|
bounty_bonus_points BIGINT NOT NULL DEFAULT 0,
|
|
FOREIGN KEY (torrent_request_id) REFERENCES torrent_requests(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE torrent_request_comments (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
torrent_request_id BIGINT NOT NULL REFERENCES torrent_requests(id) ON DELETE CASCADE,
|
|
created_by_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
content TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
|
);
|
|
CREATE TABLE torrent_reports (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
reported_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
reported_by_id INT NOT NULL,
|
|
description TEXT NOT NULL,
|
|
reported_torrent_id INT NOT NULL,
|
|
FOREIGN KEY (reported_by_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (reported_torrent_id) REFERENCES torrents(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE peers (
|
|
peer_id bytea NOT NULL,
|
|
ip INET NOT NULL,
|
|
port INT NOT NULL,
|
|
agent varchar(64) NOT NULL,
|
|
uploaded bigint NOT NULL,
|
|
downloaded bigint NOT NULL,
|
|
"left" bigint NOT NULL,
|
|
seeder boolean NOT NULL,
|
|
created_at timestamp without time zone DEFAULT NULL,
|
|
updated_at timestamp without time zone DEFAULT NULL,
|
|
torrent_id integer NOT NULL,
|
|
user_id integer NOT NULL,
|
|
-- connectable boolean NOT NULL DEFAULT FALSE,
|
|
active boolean NOT NULL,
|
|
-- visible boolean NOT NULL,
|
|
PRIMARY KEY (user_id, torrent_id, peer_id)
|
|
);
|
|
CREATE INDEX peers_idx_seeder_user_id ON peers (seeder, user_id);
|
|
CREATE INDEX peers_torrent_id_foreign ON peers (torrent_id);
|
|
CREATE INDEX peers_active_index ON peers (active);
|
|
ALTER TABLE peers
|
|
ADD CONSTRAINT peers_torrent_id_foreign FOREIGN KEY (torrent_id) REFERENCES torrents (id) ON DELETE CASCADE ON UPDATE CASCADE;
|
|
ALTER TABLE peers
|
|
ADD CONSTRAINT peers_user_id_foreign FOREIGN KEY (user_id) REFERENCES users (id) ON UPDATE CASCADE;
|
|
CREATE TABLE torrent_activities (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
torrent_id INT NOT NULL,
|
|
user_id INT NOT NULL,
|
|
snatched_at TIMESTAMP WITH TIME ZONE,
|
|
first_seen_seeding_at TIMESTAMP WITH TIME ZONE,
|
|
last_seen_seeding_at TIMESTAMP WITH TIME ZONE,
|
|
total_seed_time BIGINT NOT NULL DEFAULT 0,
|
|
uploaded BIGINT NOT NULL DEFAULT 0,
|
|
real_uploaded BIGINT NOT NULL DEFAULT 0,
|
|
downloaded BIGINT NOT NULL DEFAULT 0,
|
|
real_downloaded BIGINT NOT NULL DEFAULT 0,
|
|
|
|
FOREIGN KEY (torrent_id) REFERENCES torrents(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id),
|
|
|
|
UNIQUE (torrent_id, user_id)
|
|
);
|
|
CREATE TABLE entities (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT NOT NULL,
|
|
pictures TEXT[] NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
title_groups_amount INT NOT NULL DEFAULT 0,
|
|
edition_groups_amount INT NOT NULL DEFAULT 0,
|
|
torrents_amount INT NOT NULL DEFAULT 0,
|
|
seeders_amount INT NOT NULL DEFAULT 0,
|
|
leechers_amount INT NOT NULL DEFAULT 0,
|
|
snatches_amount INT NOT NULL DEFAULT 0,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id)
|
|
);
|
|
CREATE TYPE entity_role_enum AS ENUM (
|
|
'producer',
|
|
'developer',
|
|
'designer',
|
|
'label'
|
|
);
|
|
CREATE TABLE affiliated_entities (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title_group_id INT NOT NULL,
|
|
entity_id BIGINT NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
roles entity_role_enum[] NOT NULL,
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (entity_id) REFERENCES entities(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id) ON DELETE SET NULL
|
|
);
|
|
CREATE TYPE collage_category_enum AS ENUM (
|
|
'Personal',
|
|
'Staff Picks',
|
|
'External',
|
|
'Theme'
|
|
);
|
|
CREATE TYPE collage_type_enum AS ENUM (
|
|
'Artist',
|
|
'Entity',
|
|
'TitleGroup',
|
|
'MasterGroup'
|
|
);
|
|
CREATE TABLE collage (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
name VARCHAR NOT NULL,
|
|
cover TEXT,
|
|
description TEXT NOT NULL,
|
|
tags VARCHAR[] NOT NULL,
|
|
category collage_category_enum NOT NULL,
|
|
collage_type collage_type_enum NOT NULL,
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id)
|
|
);
|
|
CREATE TABLE collage_entry (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL REFERENCES users(id),
|
|
collage_id BIGINT NOT NULL REFERENCES collage(id),
|
|
artist_id BIGINT REFERENCES artists(id),
|
|
entity_id BIGINT REFERENCES entities(id),
|
|
title_group_id INT REFERENCES title_groups(id),
|
|
master_group_id INT REFERENCES master_groups(id),
|
|
note TEXT
|
|
);
|
|
-- prevent duplicate entries in a collage
|
|
CREATE UNIQUE INDEX unique_artist_per_collage
|
|
ON collage_entry (collage_id, artist_id)
|
|
WHERE artist_id IS NOT NULL;
|
|
CREATE UNIQUE INDEX unique_entity_per_collage
|
|
ON collage_entry (collage_id, entity_id)
|
|
WHERE entity_id IS NOT NULL;
|
|
CREATE UNIQUE INDEX unique_title_group_per_collage
|
|
ON collage_entry (collage_id, title_group_id)
|
|
WHERE title_group_id IS NOT NULL;
|
|
CREATE UNIQUE INDEX unique_master_group_per_collage
|
|
ON collage_entry (collage_id, master_group_id)
|
|
WHERE master_group_id IS NOT NULL;
|
|
-- make sure each entry matches the collage type (no title groups in an artist collage for example)
|
|
CREATE FUNCTION enforce_collage_entry_type()
|
|
RETURNS TRIGGER AS $$
|
|
DECLARE
|
|
expected_id_column TEXT;
|
|
BEGIN
|
|
SELECT
|
|
CASE collage_type
|
|
WHEN 'Artist' THEN 'artist_id'
|
|
WHEN 'Entity' THEN 'entity_id'
|
|
WHEN 'TitleGroup' THEN 'title_group_id'
|
|
WHEN 'MasterGroup' THEN 'master_group_id'
|
|
END
|
|
INTO expected_id_column
|
|
FROM collage
|
|
WHERE id = NEW.collage_id;
|
|
|
|
IF (
|
|
(expected_id_column = 'artist_id' AND NEW.artist_id IS NULL) OR
|
|
(expected_id_column = 'entity_id' AND NEW.entity_id IS NULL) OR
|
|
(expected_id_column = 'title_group_id' AND NEW.title_group_id IS NULL) OR
|
|
(expected_id_column = 'master_group_id' AND NEW.master_group_id IS NULL)
|
|
) THEN
|
|
RAISE EXCEPTION 'Collage entry must have a non-null % for collage ID %', expected_id_column, NEW.collage_id;
|
|
END IF;
|
|
|
|
IF (
|
|
(expected_id_column != 'artist_id' AND NEW.artist_id IS NOT NULL) OR
|
|
(expected_id_column != 'entity_id' AND NEW.entity_id IS NOT NULL) OR
|
|
(expected_id_column != 'title_group_id' AND NEW.title_group_id IS NOT NULL) OR
|
|
(expected_id_column != 'master_group_id' AND NEW.master_group_id IS NOT NULL)
|
|
) THEN
|
|
RAISE EXCEPTION 'Collage entry for collage ID % must not reference any other type than %', NEW.collage_id, expected_id_column;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
CREATE TRIGGER check_collage_entry_type
|
|
BEFORE INSERT OR UPDATE ON collage_entry
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION enforce_collage_entry_type();
|
|
CREATE TABLE forum_categories (
|
|
id SERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id)
|
|
);
|
|
INSERT INTO forum_categories (created_by_id, name) VALUES (1, 'Site');
|
|
CREATE TABLE forum_sub_categories (
|
|
id SERIAL PRIMARY KEY NOT NULL,
|
|
forum_category_id INT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
threads_amount BIGINT NOT NULL DEFAULT 0,
|
|
posts_amount BIGINT NOT NULL DEFAULT 0,
|
|
forbidden_classes VARCHAR(50) [] NOT NULL DEFAULT ARRAY[]::VARCHAR(50)[],
|
|
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id),
|
|
FOREIGN KEY (forum_category_id) REFERENCES forum_categories(id)
|
|
);
|
|
INSERT INTO forum_sub_categories (created_by_id, forum_category_id,name, threads_amount, posts_amount) VALUES (1, 1, 'Announcements', 1, 1);
|
|
CREATE TABLE forum_threads (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
forum_sub_category_id INT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
posts_amount BIGINT NOT NULL DEFAULT 0,
|
|
sticky BOOLEAN NOT NULL DEFAULT FALSE,
|
|
locked BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id),
|
|
FOREIGN KEY (forum_sub_category_id) REFERENCES forum_sub_categories(id)
|
|
);
|
|
INSERT INTO forum_threads (created_by_id, forum_sub_category_id, name, posts_amount) VALUES (1, 1, 'Welcome to the site!', 1);
|
|
CREATE TABLE forum_posts (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
forum_thread_id BIGINT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
content TEXT NOT NULL,
|
|
sticky BOOLEAN NOT NULL DEFAULT FALSE,
|
|
locked BOOLEAN NOT NULL DEFAULT FALSE,
|
|
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id),
|
|
FOREIGN KEY (forum_thread_id) REFERENCES forum_threads(id)
|
|
);
|
|
INSERT INTO forum_posts (created_by_id, forum_thread_id, content) VALUES (1, 1, 'Welcome!');
|
|
CREATE TABLE wiki_articles (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by_id INT NOT NULL,
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_by_id INT NOT NULL,
|
|
body TEXT NOT NULL,
|
|
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id)
|
|
);
|
|
CREATE TABLE title_group_bookmarks (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
user_id INT NOT NULL,
|
|
title_group_id INT NOT NULL,
|
|
description TEXT,
|
|
|
|
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE conversations (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
|
|
subject VARCHAR(255) NOT NULL,
|
|
sender_id INT NOT NULL,
|
|
receiver_id INT NOT NULL,
|
|
sender_last_seen_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
|
|
receiver_last_seen_at TIMESTAMP WITH TIME ZONE,
|
|
|
|
FOREIGN KEY (sender_id) REFERENCES users(id),
|
|
FOREIGN KEY (receiver_id) REFERENCES users(id)
|
|
);
|
|
CREATE TABLE conversation_messages (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
conversation_id BIGINT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
|
|
created_by_id INT NOT NULL,
|
|
content TEXT NOT NULL,
|
|
|
|
FOREIGN KEY (conversation_id) REFERENCES conversations(id),
|
|
FOREIGN KEY (created_by_id) REFERENCES users(id)
|
|
);
|
|
CREATE TABLE staff_pms (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
subject TEXT NOT NULL,
|
|
created_by_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
resolved BOOLEAN NOT NULL DEFAULT FALSE
|
|
);
|
|
CREATE TABLE staff_pm_messages (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
staff_pm_id BIGINT NOT NULL REFERENCES staff_pms(id) ON DELETE CASCADE,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
created_by_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
content TEXT NOT NULL
|
|
);
|
|
-- notifies of new posts within a thread
|
|
CREATE TABLE subscriptions_forum_thread_posts (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
forum_thread_id BIGINT NOT NULL,
|
|
user_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
FOREIGN KEY (forum_thread_id) REFERENCES forum_threads(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
UNIQUE (forum_thread_id, user_id)
|
|
);
|
|
CREATE TABLE notifications_forum_thread_posts (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
forum_thread_id BIGINT NOT NULL,
|
|
forum_post_id BIGINT NOT NULL,
|
|
user_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
read_status BOOLEAN NOT NULL DEFAULT FALSE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id),
|
|
FOREIGN KEY (forum_post_id) REFERENCES forum_posts(id) ON DELETE CASCADE
|
|
);
|
|
-- notifies of new torrents within a title group
|
|
CREATE TABLE subscriptions_title_group_torrents (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
title_group_id INT NOT NULL,
|
|
user_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
FOREIGN KEY (title_group_id) REFERENCES title_groups(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
|
|
UNIQUE (title_group_id, user_id)
|
|
);
|
|
CREATE TABLE notifications_title_group_torrents (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
torrent_id INT NOT NULL,
|
|
user_id INT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
read_status BOOLEAN NOT NULL DEFAULT FALSE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id),
|
|
FOREIGN KEY (torrent_id) REFERENCES torrents(id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Views
|
|
|
|
CREATE VIEW torrents_and_reports AS
|
|
SELECT
|
|
t.id,
|
|
t.upload_factor,
|
|
t.download_factor,
|
|
t.seeders,
|
|
t.leechers,
|
|
t.times_completed,
|
|
t.snatched,
|
|
t.edition_group_id,
|
|
t.created_at,
|
|
t.updated_at,
|
|
-- Always keep the actual created_by_id for internal queries
|
|
t.created_by_id,
|
|
-- Add display fields that respect anonymity
|
|
CASE
|
|
WHEN t.uploaded_as_anonymous THEN NULL
|
|
ELSE t.created_by_id
|
|
END as display_created_by_id,
|
|
CASE
|
|
WHEN t.uploaded_as_anonymous THEN NULL
|
|
ELSE json_build_object('id', u.id, 'username', u.username)
|
|
END AS display_created_by,
|
|
t.info_hash,
|
|
t.extras,
|
|
t.languages,
|
|
t.release_name,
|
|
t.release_group,
|
|
t.description,
|
|
t.file_amount_per_type,
|
|
t.uploaded_as_anonymous,
|
|
t.file_list,
|
|
t.mediainfo,
|
|
t.trumpable,
|
|
t.staff_checked,
|
|
t.container,
|
|
t.size,
|
|
t.duration,
|
|
t.audio_codec,
|
|
t.audio_bitrate,
|
|
t.audio_bitrate_sampling,
|
|
t.audio_channels,
|
|
t.video_codec,
|
|
t.features,
|
|
t.subtitle_languages,
|
|
t.video_resolution,
|
|
t.video_resolution_other_x,
|
|
t.video_resolution_other_y,
|
|
(EXISTS (
|
|
SELECT 1
|
|
FROM torrent_reports tr
|
|
WHERE tr.reported_torrent_id = t.id
|
|
)) AS reported,
|
|
CASE
|
|
WHEN EXISTS (SELECT 1 FROM torrent_reports WHERE reported_torrent_id = t.id) THEN json_agg(row_to_json(tr))
|
|
ELSE '[]'::json
|
|
END AS reports
|
|
FROM
|
|
torrents t
|
|
LEFT JOIN
|
|
torrent_reports tr ON t.id = tr.reported_torrent_id
|
|
LEFT JOIN
|
|
users u ON t.created_by_id = u.id
|
|
WHERE t.deleted_at IS NULL
|
|
GROUP BY
|
|
t.id, u.id
|
|
ORDER BY
|
|
t.id;
|
|
|
|
CREATE VIEW get_title_groups_and_edition_group_and_torrents_lite AS
|
|
WITH edition_groups_with_torrents AS (
|
|
SELECT
|
|
eg.id AS eg_id,
|
|
eg.title_group_id,
|
|
jsonb_build_object(
|
|
'id', eg.id,
|
|
'title_group_id', eg.title_group_id,
|
|
'name', eg.name,
|
|
'release_date', eg.release_date,
|
|
'distributor', eg.distributor,
|
|
'covers', eg.covers,
|
|
'source', eg.source,
|
|
'additional_information', eg.additional_information,
|
|
'torrents', COALESCE(jsonb_agg(
|
|
jsonb_build_object(
|
|
'id', tar.id, 'upload_factor', tar.upload_factor, 'download_factor', tar.download_factor,
|
|
'seeders', tar.seeders, 'leechers', tar.leechers, 'times_completed', tar.times_completed,
|
|
'edition_group_id', tar.edition_group_id, 'created_at', tar.created_at, 'extras', tar.extras,
|
|
'release_name', tar.release_name, 'release_group', tar.release_group,
|
|
'file_amount_per_type', tar.file_amount_per_type, 'trumpable', tar.trumpable,
|
|
'staff_checked', tar.staff_checked, 'languages', tar.languages,
|
|
'container', tar.container, 'size', tar.size, 'duration', tar.duration,
|
|
'audio_codec', tar.audio_codec, 'audio_bitrate', tar.audio_bitrate,
|
|
'audio_bitrate_sampling', tar.audio_bitrate_sampling, 'audio_channels', tar.audio_channels,
|
|
'video_codec', tar.video_codec, 'features', tar.features,
|
|
'subtitle_languages', tar.subtitle_languages, 'video_resolution', tar.video_resolution,
|
|
'video_resolution_other_x', tar.video_resolution_other_x, 'video_resolution_other_y', tar.video_resolution_other_y,
|
|
'reports', tar.reports
|
|
) ORDER BY tar.id
|
|
) FILTER (WHERE tar.id IS NOT NULL), '[]'::jsonb)
|
|
) AS eg_data,
|
|
MIN(tar.created_at) AS min_torrent_created_at,
|
|
MAX(tar.created_at) AS max_torrent_created_at,
|
|
MIN(tar.size) AS min_torrent_size,
|
|
MAX(tar.size) AS max_torrent_size
|
|
FROM
|
|
edition_groups eg
|
|
LEFT JOIN torrents_and_reports tar ON eg.id = tar.edition_group_id
|
|
GROUP BY
|
|
eg.id
|
|
),
|
|
affiliated_artists_data AS (
|
|
SELECT
|
|
aa.title_group_id,
|
|
jsonb_agg(
|
|
jsonb_build_object(
|
|
'id', ar.id,
|
|
'name', ar.name
|
|
) ORDER BY ar.name
|
|
) AS affiliated_artists
|
|
FROM
|
|
affiliated_artists aa
|
|
JOIN artists ar ON aa.artist_id = ar.id
|
|
GROUP BY
|
|
aa.title_group_id
|
|
)
|
|
SELECT
|
|
tgr.id AS title_group_id,
|
|
jsonb_build_object(
|
|
'id', tgr.id,
|
|
'name', tgr.name,
|
|
'covers', tgr.covers,
|
|
'category', tgr.category,
|
|
'content_type', tgr.content_type,
|
|
-- 'tags', tgr.tags,
|
|
'original_release_date', tgr.original_release_date,
|
|
'platform', tgr.platform
|
|
) || jsonb_build_object(
|
|
'edition_groups', COALESCE(jsonb_agg(egwt.eg_data ORDER BY egwt.eg_id) FILTER (WHERE egwt.eg_data IS NOT NULL), '[]'::jsonb),
|
|
'affiliated_artists', COALESCE(aad.affiliated_artists, '[]'::jsonb)
|
|
) AS title_group_data
|
|
FROM
|
|
title_groups tgr
|
|
LEFT JOIN edition_groups_with_torrents egwt ON tgr.id = egwt.title_group_id
|
|
LEFT JOIN affiliated_artists_data aad ON tgr.id = aad.title_group_id
|
|
GROUP BY
|
|
tgr.id, tgr.name, tgr.covers, tgr.category, tgr.content_type, tgr.original_release_date, tgr.platform, aad.affiliated_artists
|
|
ORDER BY
|
|
tgr.original_release_date DESC,
|
|
tgr.id ASC;
|
|
|
|
|
|
CREATE MATERIALIZED VIEW title_group_hierarchy_lite AS
|
|
SELECT
|
|
title_groups.id AS title_group_id,
|
|
title_groups.name AS title_group_name,
|
|
title_groups.covers AS title_group_covers,
|
|
title_groups.category AS title_group_category,
|
|
title_groups.content_type AS title_group_content_type,
|
|
title_groups.platform AS title_group_platform,
|
|
title_groups.original_release_date AS title_group_original_release_date,
|
|
title_groups.external_links AS title_group_external_links,
|
|
tg_tags.tag_ids AS title_group_tag_ids,
|
|
tg_tags.tag_names AS title_group_tag_names,
|
|
|
|
series.id AS title_group_series_id,
|
|
series.name AS title_group_series_name,
|
|
|
|
edition_groups.id AS edition_group_id,
|
|
edition_groups.name AS edition_group_name,
|
|
edition_groups.release_date AS edition_group_release_date,
|
|
edition_groups.distributor AS edition_group_distributor,
|
|
edition_groups.covers AS edition_group_covers,
|
|
edition_groups.source AS edition_group_source,
|
|
edition_groups.additional_information AS edition_group_additional_information,
|
|
|
|
torrents.id AS torrent_id,
|
|
torrents.created_by_id AS torrent_created_by_id,
|
|
torrents.uploaded_as_anonymous AS torrent_uploaded_as_anonymous,
|
|
torrents.upload_factor AS torrent_upload_factor,
|
|
torrents.download_factor AS torrent_download_factor,
|
|
torrents.seeders AS torrent_seeders,
|
|
torrents.leechers AS torrent_leechers,
|
|
torrents.times_completed AS torrent_times_completed,
|
|
torrents.snatched AS torrent_snatched,
|
|
torrents.edition_group_id AS torrent_edition_group_id,
|
|
torrents.created_at AS torrent_created_at,
|
|
torrents.extras AS torrent_extras,
|
|
torrents.release_name AS torrent_release_name,
|
|
torrents.release_group AS torrent_release_group,
|
|
torrents.file_amount_per_type AS torrent_file_amount_per_type,
|
|
torrents.trumpable AS torrent_trumpable,
|
|
torrents.staff_checked AS torrent_staff_checked,
|
|
torrents.languages AS torrent_languages,
|
|
torrents.container AS torrent_container,
|
|
torrents.size AS torrent_size,
|
|
torrents.duration AS torrent_duration,
|
|
torrents.audio_codec AS torrent_audio_codec,
|
|
torrents.audio_bitrate AS torrent_audio_bitrate,
|
|
torrents.audio_bitrate_sampling AS torrent_audio_bitrate_sampling,
|
|
torrents.audio_channels AS torrent_audio_channels,
|
|
torrents.video_codec AS torrent_video_codec,
|
|
torrents.features AS torrent_features,
|
|
torrents.subtitle_languages AS torrent_subtitle_languages,
|
|
torrents.video_resolution AS torrent_video_resolution,
|
|
torrents.video_resolution_other_x AS torrent_video_resolution_other_x,
|
|
torrents.video_resolution_other_y AS torrent_video_resolution_other_y,
|
|
(EXISTS (
|
|
SELECT 1
|
|
FROM torrent_reports tr
|
|
WHERE tr.reported_torrent_id = torrents.id
|
|
)) AS torrent_reported
|
|
FROM title_groups
|
|
LEFT JOIN LATERAL (
|
|
SELECT
|
|
COALESCE(
|
|
ARRAY(
|
|
SELECT tat.tag_id
|
|
FROM title_group_applied_tags tat
|
|
WHERE tat.title_group_id = title_groups.id
|
|
),
|
|
ARRAY[]::int[]
|
|
) AS tag_ids,
|
|
COALESCE(
|
|
ARRAY(
|
|
SELECT t.name
|
|
FROM title_group_applied_tags tat
|
|
JOIN title_group_tags t ON t.id = tat.tag_id
|
|
WHERE tat.title_group_id = title_groups.id
|
|
),
|
|
ARRAY[]::text[]
|
|
) AS tag_names
|
|
) tg_tags ON TRUE
|
|
LEFT JOIN edition_groups ON edition_groups.title_group_id = title_groups.id
|
|
LEFT JOIN torrents ON torrents.edition_group_id = edition_groups.id
|
|
LEFT JOIN series ON series.id = title_groups.series_id;
|
|
|
|
-- refresh the materialized view anytime something it depends on changes
|
|
create function refresh_materialized_view_title_group_hierarchy_lite()
|
|
returns trigger language plpgsql
|
|
as $$
|
|
begin
|
|
refresh materialized view title_group_hierarchy_lite;
|
|
return null;
|
|
end $$;
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on torrents for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on edition_groups for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on title_groups for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on torrent_reports for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on series for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|
|
|
|
create trigger refresh_materialized_view_title_group_hierarchy_lite
|
|
after insert or update or delete or truncate
|
|
on title_group_applied_tags for each statement
|
|
execute procedure refresh_materialized_view_title_group_hierarchy_lite();
|