canape/sql/migration/0001_initial.up.sql

102 lines
3.4 KiB
PL/PgSQL

-- Enable UUID generation
CREATE EXTENSION IF NOT EXISTS pgcrypto;
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END; $$ language 'plpgsql';
CREATE TABLE base (
updated_at timestamp with time zone DEFAULT current_timestamp,
created_at timestamp with time zone DEFAULT current_timestamp
);
CREATE TABLE users (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
name text NOT NULL UNIQUE,
hash text NOT NULL,
admin boolean DEFAULT false,
rawconfig json DEFAULT '{}',
LIKE base INCLUDING DEFAULTS
);
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TABLE tokens (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
value text NOT NULL UNIQUE,
user_id uuid REFERENCES users (id) ON DELETE CASCADE,
LIKE base INCLUDING DEFAULTS
);
CREATE TRIGGER update_tokens_updated_at BEFORE UPDATE ON tokens FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TABLE shows (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
imdb_id text NOT NULL UNIQUE,
title text NOT NULL,
rating real NOT NULL,
plot text NOT NULL,
tvdb_id text NOT NULL,
year smallint NOT NULL,
first_aired timestamp with time zone,
LIKE base INCLUDING DEFAULTS
);
CREATE UNIQUE INDEX ON shows (imdb_id);
CREATE TRIGGER update_shows_updated_at BEFORE UPDATE ON shows FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TABLE episodes (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
imdb_id text NOT NULL,
show_imdb_id text REFERENCES shows (imdb_id) ON DELETE CASCADE,
show_tvdb_id text NOT NULL,
title text NOT NULL,
season smallint NOT NULL,
episode smallint NOT NULL,
tvdb_id text NOT NULL,
aired text NOT NULL,
plot text NOT NULL,
runtime smallint NOT NULL,
rating real NOT NULL,
LIKE base INCLUDING DEFAULTS
);
CREATE INDEX ON episodes (show_imdb_id, season);
CREATE UNIQUE INDEX ON episodes (show_imdb_id, season, episode);
CREATE TRIGGER update_episodes_updated_at BEFORE UPDATE ON episodes FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TABLE shows_tracked (
imdb_id text NOT NULL REFERENCES shows (imdb_id) ON DELETE CASCADE,
user_id uuid NOT NULL REFERENCES users (id) ON DELETE CASCADE,
season smallint NOT NULL,
episode smallint NOT NULL
);
CREATE UNIQUE INDEX ON shows_tracked (imdb_id, user_id);
CREATE INDEX ON shows_tracked (user_id);
CREATE TABLE movies (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
imdb_id text NOT NULL UNIQUE,
title text NOT NULL,
rating real NOT NULL,
votes integer NOT NULL,
plot text NOT NULL,
tmdb_id integer NOT NULL,
year smallint NOT NULL,
original_title text NOT NULL,
runtime integer NOT NULL,
sort_title text NOT NULL,
tagline text NOT NULL,
genres text[] NOT NULL,
LIKE base INCLUDING DEFAULTS
);
CREATE INDEX ON movies (imdb_id);
CREATE TRIGGER update_movies_updated_at BEFORE UPDATE ON movies FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TABLE movies_tracked (
imdb_id text NOT NULL REFERENCES movies (imdb_id) ON DELETE CASCADE,
user_id uuid NOT NULL REFERENCES users (id) ON DELETE CASCADE
);
CREATE UNIQUE INDEX ON movies_tracked (imdb_id, user_id);
CREATE INDEX ON movies_tracked (user_id);