diff --git a/db/db.ddl b/db/db.ddl index 418019ce02be9f679c12cb6468f3df8c918be40c..419f89fa905e735a75aeb5af7e9d728147ed8810 100644 --- a/db/db.ddl +++ b/db/db.ddl @@ -38,12 +38,14 @@ CREATE TABLE places ( -- 4 škola / soutěžní místo parent int REFERENCES places(place_id), -- NULL pro root name varchar(255) COLLATE "cs_CZ", -- oficiální jméno - code varchar(255) COLLATE "cs_CZ", -- zkratka pro zadávání + code varchar(255) UNIQUE COLLATE "cs_CZ", -- zkratka pro zadávání type place_type NOT NULL, nuts varchar(255) UNIQUE DEFAULT NULL, -- evropský NUTS/LAU kód regionu note text NOT NULL DEFAULT '' -- uživatelská poznámka ); +CREATE INDEX places_parent_index ON places (parent); + -- Rekurzivní dotaz na nadřazené regiony: -- WITH RECURSIVE parent_regions(parent, place_id) AS ( -- SELECT parent, place_id FROM places WHERE place_id=... @@ -132,6 +134,8 @@ CREATE TABLE participations ( PRIMARY KEY (user_id, contest_id) ); +CREATE INDEX participations_contest_id_index ON participations (contest_id, place_id); + -- Úloha CREATE TABLE tasks ( task_id serial PRIMARY KEY, @@ -161,6 +165,9 @@ CREATE TABLE papers ( note text NOT NULL DEFAULT '' -- komentář uploadujícího ); +CREATE INDEX papers_for_task_index ON papers (for_task); +CREATE INDEX papers_for_user_index ON papers (for_user); + -- Odevzdané řešení CREATE TABLE solutions ( task_id int NOT NULL REFERENCES tasks(task_id), @@ -171,6 +178,8 @@ CREATE TABLE solutions ( PRIMARY KEY (task_id, user_id) ); +CREATE INDEX solutions_user_id_index ON solutions (user_id); + -- Historie přidělování bodů CREATE TABLE points_history ( points_history_id serial PRIMARY KEY, @@ -181,6 +190,8 @@ CREATE TABLE points_history ( points_at timestamp with time zone NOT NULL -- a kdy ); +CREATE INDEX points_history_index ON points_history (task_id, participant_id); + -- Organizátorská role CREATE TYPE role_type AS ENUM ( 'garant', -- celostátní garant (může být omezený na kategorii) @@ -225,6 +236,8 @@ CREATE TABLE log ( details jsonb NOT NULL -- detaily (závislé na typu) ); +CREATE INDEX log_type_id_index ON log (type, id); + -- Asynchronní úlohy CREATE TYPE job_type AS ENUM ( diff --git a/db/upgrade-20210111.sql b/db/upgrade-20210111.sql index 78ee9b8cfcd610774c40f6889235176ba68cc2ad..9511ceab1cb98ff9e7135f7b985fafcd110a6e4a 100644 --- a/db/upgrade-20210111.sql +++ b/db/upgrade-20210111.sql @@ -54,3 +54,12 @@ CREATE TABLE jobs ( in_file varchar(255) DEFAULT NULL, out_file varchar(255) DEFAULT NULL ); + +ALTER TABLE places ADD CONSTRAINT "places_code_key" UNIQUE (code); +CREATE INDEX places_parent_index ON places (parent); +CREATE INDEX participations_contest_id_index ON participations (contest_id, place_id); +CREATE INDEX papers_for_task_index ON papers (for_task); +CREATE INDEX papers_for_user_index ON papers (for_user); +CREATE INDEX solutions_user_id_index ON solutions (user_id); +CREATE INDEX points_history_index ON points_history (task_id, participant_id); +CREATE INDEX log_type_id_index ON log (type, id);