canape/sql/0001_initial.up.sql

90 lines
2.9 KiB
PL/PgSQL

-- Enable UUID generation
CREATE EXTENSION IF NOT EXISTS pgcrypto;
CREATE OR REPLACE FUNCTION update_modified_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END; $$ language 'plpgsql';
CREATE TABLE base (
updated_at timestamp DEFAULT current_timestamp,
created_at timestamp DEFAULT current_timestamp
);
CREATE TABLE users (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
name text NOT NULL UNIQUE,
hash text NOT NULL,
LIKE base INCLUDING DEFAULTS
);
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE PROCEDURE update_modified_column();
CREATE TABLE tokens (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
value text NOT NULL UNIQUE,
users_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_modified_column();
CREATE TABLE shows (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
imdbid text NOT NULL UNIQUE,
title text NOT NULL,
rating real NOT NULL,
plot text NOT NULL,
tvdbid text NOT NULL,
year smallint NOT NULL,
firstaired timestamp,
LIKE base INCLUDING DEFAULTS
);
CREATE INDEX ON shows (imdbid);
CREATE TRIGGER update_shows_updated_at BEFORE UPDATE ON shows FOR EACH ROW EXECUTE PROCEDURE update_modified_column();
CREATE TABLE episodes (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
shows_id uuid REFERENCES shows (id) ON DELETE CASCADE,
title text NOT NULL,
season integer NOT NULL,
episode integer NOT NULL,
tvdbid text NOT NULL,
aired text NOT NULL,
plot text NOT NULL,
runtime smallint NOT NULL,
rating real NOT NULL,
imdbid text NOT NULL,
LIKE base INCLUDING DEFAULTS
);
CREATE INDEX ON episodes (shows_id, season);
CREATE INDEX ON episodes (shows_id, season, episode);
CREATE TRIGGER update_episodes_updated_at BEFORE UPDATE ON episodes FOR EACH ROW EXECUTE PROCEDURE update_modified_column();
CREATE TABLE shows_tracked (
shows_id uuid NOT NULL REFERENCES shows (id) ON DELETE CASCADE,
users_id uuid NOT NULL REFERENCES users (id) ON DELETE CASCADE,
season integer NOT NULL,
episode integer NOT NULL
);
CREATE INDEX ON shows_tracked (shows_id, users_id);
CREATE INDEX ON shows_tracked (users_id);
CREATE TABLE movies (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
imdbid text NOT NULL UNIQUE,
title text NOT NULL,
rating real NOT NULL,
votes integer NOT NULL,
plot text NOT NULL,
tmdbid integer NOT NULL,
year smallint NOT NULL,
originaltitle text NOT NULL,
runtime integer NOT NULL,
sorttitle text NOT NULL,
tagline text NOT NULL,
LIKE base INCLUDING DEFAULTS
);
CREATE INDEX ON movies (imdbid);
CREATE TRIGGER update_movies_updated_at BEFORE UPDATE ON movies FOR EACH ROW EXECUTE PROCEDURE update_modified_column();