Files
seshat/backend/database.postgres.sql

141 lines
3.5 KiB
SQL

CREATE SCHEMA IF NOT EXISTS seshat;
SET
search_path TO seshat;
DROP TABLE IF EXISTS api_keys;
DROP TABLE IF EXISTS book_statuses;
DROP TABLE IF EXISTS book_origins;
DROP TABLE IF EXISTS refresh_tokens;
DROP TABLE IF EXISTS users;
DROP TABLE IF EXISTS books;
DROP TABLE IF EXISTS series;
CREATE TABLE
series (
series_id uuid DEFAULT gen_random_uuid (),
-- 3rd party used to fetch the data for this series.
provider varchar(6) NOT NULL,
provider_series_id text,
series_title text NOT NULL,
date_added timestamp default NULL,
PRIMARY KEY (series_id)
);
ALTER TABLE series
ALTER COLUMN date_added
SET DEFAULT now ();
CREATE INDEX series_series_title_idx ON series USING HASH (series_title);
CREATE TABLE
books (
book_id uuid DEFAULT gen_random_uuid (),
series_id uuid,
provider_book_id text NOT NULL,
isbn varchar(16),
book_title text NOT NULL,
book_desc text NOT NULL,
book_volume integer,
date_released timestamp default NULL,
date_added timestamp default NULL,
PRIMARY KEY (book_id),
FOREIGN KEY (series_id) REFERENCES series (series_id)
);
ALTER TABLE books
ALTER COLUMN date_released
SET DEFAULT now ();
ALTER TABLE books
ALTER COLUMN date_added
SET DEFAULT now ();
CREATE INDEX books_series_id_idx ON books USING HASH (series_id);
CREATE INDEX books_isbn_idx ON books USING HASH (isbn);
CREATE INDEX books_book_title_idx ON books USING HASH (book_title);
CREATE TABLE
book_origins (
book_id uuid,
origin_type varchar(8),
origin_value text,
PRIMARY KEY (book_id, origin_type, origin_value)
);
CREATE INDEX book_origins_book_id_idx ON book_origins USING HASH (book_id);
CREATE INDEX book_origins_type_value_idx ON book_origins (origin_type, origin_value);
CREATE TABLE
users (
user_id uuid DEFAULT gen_random_uuid (),
user_login varchar(24),
user_name varchar(64),
password text NOT NULL,
salt bigint NOT NULL,
is_admin boolean NOT NULL,
date_joined timestamp default NULL,
PRIMARY KEY (user_id),
UNIQUE (user_login)
);
ALTER TABLE users
ALTER COLUMN date_joined
SET DEFAULT now ();
CREATE INDEX users_user_login_idx ON users USING HASH (user_login);
CREATE TABLE
refresh_tokens (
user_id uuid NOT NULL,
refresh_token_hash text NOT NULL,
exp timestamp NOT NULL,
PRIMARY KEY (user_id, refresh_token_hash),
FOREIGN KEY (user_id) REFERENCES users (user_id)
);
CREATE TABLE
book_statuses (
user_id uuid,
book_id uuid,
state varchar(12),
date_added timestamp default NULL,
date_modified timestamp default NULL,
PRIMARY KEY (user_id, book_id),
FOREIGN KEY (user_id) REFERENCES users (user_id),
FOREIGN KEY (book_id) REFERENCES books (book_id)
);
ALTER TABLE book_statuses
ALTER COLUMN date_added
SET DEFAULT now ();
ALTER TABLE book_statuses
ALTER COLUMN date_modified
SET DEFAULT now ();
CREATE INDEX book_statuses_user_id_login_idx ON users USING HASH (user_id);
CREATE TABLE
api_keys (
user_id uuid,
api_key char(64),
date_added timestamp default NULL,
PRIMARY KEY (user_id, api_key),
FOREIGN KEY (user_id) REFERENCES users (user_id)
);
ALTER TABLE api_keys
ALTER COLUMN date_added
SET DEFAULT now ();
CREATE INDEX api_keys_api_key_idx ON api_keys USING HASH (api_key);