108 lines
3.3 KiB
SQL
108 lines
3.3 KiB
SQL
-- Lookup (aka artists)
|
|
CREATE TABLE lookup(
|
|
"id" varchar(255) NOT NULL,
|
|
"name" varchar(255) NOT NULL,
|
|
"service" varchar(20) NOT NULL,
|
|
"indexed" timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
public_id text,
|
|
relation_id integer,
|
|
PRIMARY KEY (id, service)
|
|
);
|
|
|
|
CREATE TABLE creators(
|
|
creator_id text NOT NULL,
|
|
service text NOT NULL,
|
|
creator_name text NOT NULL,
|
|
creator_slug text,
|
|
creator_internal_id text,
|
|
short_description text NOT NULL,
|
|
description text NOT NULL,
|
|
icon text,
|
|
banner text,
|
|
is_nsfw boolean,
|
|
deleted_at timestamp without time zone,
|
|
stopped_at timestamp without time zone,
|
|
paused_at timestamp without time zone,
|
|
post_count integer,
|
|
media_count integer,
|
|
tiers jsonb[],
|
|
access_groups jsonb[],
|
|
published_at timestamp without time zone,
|
|
added_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
|
updated_at timestamp without time zone,
|
|
public_posts_refreshed_at timestamp without time zone,
|
|
public_posts_full_refreshed_at timestamp without time zone,
|
|
CONSTRAINT creators_pkey PRIMARY KEY (creator_id, service)
|
|
);
|
|
|
|
CREATE TABLE creators_revisions(
|
|
revision_id serial NOT NULL PRIMARY KEY,
|
|
creator_id text NOT NULL,
|
|
service text NOT NULL,
|
|
creator_name text NOT NULL,
|
|
creator_slug text,
|
|
creator_internal_id text,
|
|
short_description text NOT NULL,
|
|
description text NOT NULL,
|
|
icon text,
|
|
banner text,
|
|
is_nsfw boolean,
|
|
deleted_at timestamp without time zone,
|
|
stopped_at timestamp without time zone,
|
|
paused_at timestamp without time zone,
|
|
post_count integer,
|
|
media_count integer,
|
|
tiers jsonb[],
|
|
access_groups jsonb[],
|
|
published_at timestamp without time zone,
|
|
added_at timestamp without time zone DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
|
updated_at timestamp without time zone,
|
|
public_posts_refreshed_at timestamp without time zone,
|
|
public_posts_full_refreshed_at timestamp without time zone
|
|
);
|
|
|
|
CREATE TYPE unapproved_link_status AS ENUM(
|
|
'pending',
|
|
'approved',
|
|
'rejected'
|
|
);
|
|
|
|
CREATE TABLE unapproved_link_requests(
|
|
id int PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
|
from_service text NOT NULL,
|
|
from_id text NOT NULL,
|
|
to_service text NOT NULL,
|
|
to_id text NOT NULL,
|
|
reason text,
|
|
requester_id int NOT NULL REFERENCES account(id),
|
|
status unapproved_link_status NOT NULL DEFAULT 'pending',
|
|
FOREIGN KEY (from_service, from_id) REFERENCES lookup(service, id),
|
|
FOREIGN KEY (to_service, to_id) REFERENCES lookup(service, id),
|
|
UNIQUE (from_service, from_id, to_service, to_id)
|
|
);
|
|
|
|
CREATE INDEX name_idx ON lookup USING btree("name");
|
|
|
|
CREATE INDEX lookup_id_idx ON lookup USING btree("id");
|
|
|
|
CREATE INDEX lookup_service_idx ON lookup USING btree("service");
|
|
|
|
CREATE INDEX lookup_indexed_idx ON lookup USING btree("indexed");
|
|
|
|
CREATE SEQUENCE lookup_relation_id_seq;
|
|
|
|
CREATE INDEX lookup_relation_id_index ON lookup USING btree(relation_id);
|
|
|
|
CREATE INDEX lookup_public_id_idx ON lookup(public_id);
|
|
|
|
CREATE INDEX lookup_relation_id_idx ON lookup(relation_id);
|
|
|
|
-- the migrations refer to `updated_idx` index
|
|
-- but it wasn't declared prior being changed
|
|
CREATE INDEX updated_idx ON lookup USING btree("updated");
|
|
|
|
CREATE INDEX creators_revisions_creator_id_service_idx ON creators_revisions USING btree(creator_id, service);
|
|
|
|
CREATE INDEX unapproved_link_requests_status_id_idx ON unapproved_link_requests(status, id);
|