otter-space-sdk/pkg/database/migrations/001_inital_database.sql
soxx 6f814e5b21
All checks were successful
Gitea Build Check / Build (pull_request) Successful in 3m8s
refactor: unified migrations and Tag* ID Changes
- unified the migrations
- added new IDs for Tag, TagAlias, TagGroup
- changed relevant functions to use the given IDs

BREAKING-CHANGE: Database needs to be cleared or migrated. Not compatible with Database v5
2025-01-28 13:27:11 +01:00

200 lines
5.6 KiB
SQL

-- +migrate Up
CREATE TYPE Rating AS ENUM (
'safe',
'questionable',
'explicit',
'unknown'
);
CREATE TYPE TagType AS ENUM (
'general',
'species',
'character',
'artist',
'lore',
'meta',
'invalid',
'copyright',
'Contributor',
'Unknown'
);
CREATE TYPE ReportType AS ENUM (
'duplicate',
'missing_data',
'rating_abuse',
'illegal_content'
);
CREATE TYPE ReportState AS ENUM (
'pending_unclaimed',
'pending',
'approved',
'partial',
'rejected'
);
CREATE TYPE pool_category AS ENUM (
'series',
'collection'
);
CREATE TABLE "User"
(
id TEXT PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL
);
CREATE TABLE "Post"
(
id CHAR(25) PRIMARY KEY,
rating Rating,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL NULL
);
CREATE TABLE "Source"
(
id CHAR(25) PRIMARY KEY,
display_name TEXT NULL,
icon TEXT NULL,
domain TEXT NOT NULL UNIQUE,
enabled BOOL DEFAULT FALSE,
meta JSON DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL
);
CREATE TABLE "PostReference"
(
post_id CHAR(25) REFERENCES "Post" (id),
source_id CHAR(25) REFERENCES "Source" (id),
url TEXT NOT NULL,
full_file_url TEXT,
preview_file_url TEXT,
sample_file_url TEXT,
source_post_id TEXT,
PRIMARY KEY (post_id, source_id, url)
);
CREATE TABLE "Tag"
(
id SERIAL PRIMARY KEY,
name TEXT UNIQUE,
tag_type TagType,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL
);
CREATE TABLE "TagAlias"
(
id SERIAL PRIMARY KEY,
name TEXT UNIQUE,
tag_id INT REFERENCES "Tag" (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE "TagGroup"
(
id SERIAL PRIMARY KEY,
name TEXT UNIQUE,
tag_id INT REFERENCES "Tag" (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE "UserSource"
(
id CHAR(25) PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL NULL,
user_id CHAR(25) REFERENCES "User" (id),
source_id TEXT REFERENCES "Source" (id),
scrape_time_interval TEXT,
account_username TEXT,
account_id TEXT,
last_scrape_time TIMESTAMP WITH TIME ZONE,
account_validate BOOL DEFAULT FALSE,
account_validation_key CHAR(25),
UNIQUE (source_id, account_username, account_id)
);
CREATE TABLE "UserFavorites"
(
id CHAR(25) PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL NULL,
user_id TEXT REFERENCES "User" (id),
post_id CHAR(25) REFERENCES "Post" (id),
user_source_id CHAR(25) REFERENCES "UserSource" (id)
);
CREATE INDEX idx_user_post_deleted ON "UserFavorites"(user_id, deleted_at);
CREATE INDEX idx_created_at ON "UserFavorites"(created_at);
CREATE TABLE "post_tags"
(
post_id CHAR(25) REFERENCES "Post" (id),
tag_id INT REFERENCES "Tag" (id),
PRIMARY KEY (post_id, tag_id)
);
CREATE TABLE "Pool"
(
id CHAR(25) PRIMARY KEY,
name TEXT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL,
category POOL_CATEGORY NOT NULL
);
CREATE TABLE "PoolPost"
(
pool_id CHAR(25) REFERENCES "Pool" (id),
post_id CHAR(25) REFERENCES "Post" (id),
order_position INT NOT NULL DEFAULT 0,
PRIMARY KEY (pool_id, post_id)
);
CREATE TABLE "PoolReference"
(
pool_id CHAR(25) REFERENCES "Pool" (id),
source_id CHAR(25) REFERENCES "Source" (id),
url TEXT NOT NULL,
PRIMARY KEY (pool_id, source_id, url)
);
CREATE TABLE "ScrapeHistory"
(
id CHAR(25) PRIMARY KEY,
user_source_id CHAR(25) NOT NULL REFERENCES "UserSource" (id),
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
finished_at TIMESTAMP NULL,
error TEXT NULL,
added_posts INT NOT NULL,
deleted_posts INT NOT NULL
);
CREATE TABLE "PostReport"
(
id CHAR(25) NOT NULL PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP WITH TIME ZONE NULL,
post_id CHAR(25) NOT NULL REFERENCES "Post" (id),
report_by TEXT NOT NULL REFERENCES "User" (id),
report_description TEXT NOT NULL,
audit_by TEXT NULL REFERENCES "User" (id),
audit_description TEXT NOT NULL,
report_type ReportType NOT NULL,
report_state ReportState NOT NULL
);