-- +goose Up -- +goose StatementBegin --CREATE TABLE IF NOT EXISTS languages --( -- id serial NOT NULL, -- name VARCHAR(60) NOT NULL, -- build_file_hash CHAR(128) NULL, -- execute_file_hash CHAR(128) NULL, -- created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- -- PRIMARY KEY (id) --); CREATE TABLE IF NOT EXISTS problems ( id serial NOT NULL, name VARCHAR(300) NOT NULL, description TEXT NOT NULL, time_limit INT NOT NULL, memory_limit INT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), PRIMARY KEY(id) ); CREATE INDEX ON problems USING BTREE (id); CREATE TABLE IF NOT EXISTS contests ( id serial NOT NULL, name VARCHAR(300) NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), PRIMARY KEY(id) ); CREATE INDEX ON contests USING BTREE (id); CREATE TABLE IF NOT EXISTS tasks ( id SERIAL NOT NULL, contest_id INT REFERENCES contests ON DELETE CASCADE, problem_id INT REFERENCES problems ON DELETE CASCADE, position INT NOT NULL, position_name VARCHAR(10) NOT NULL, -- problem name like: A,B,A1,etc UNIQUE (contest_id,problem_id), UNIQUE (contest_id,position), UNIQUE (contest_id,position_name), PRIMARY KEY (id) ); CREATE INDEX ON tasks USING BTREE (id); CREATE INDEX ON tasks USING BTREE (contest_id); CREATE INDEX ON tasks USING BTREE (problem_id); CREATE TABLE IF NOT EXISTS testgroups ( id serial NOT NULL, problem_id INT REFERENCES problems ON DELETE CASCADE, testing_strategy INT NOT NULL, PRIMARY KEY (id) ); CREATE INDEX ON testgroups USING BTREE (id); CREATE INDEX ON testgroups USING BTREE (problem_id); CREATE TABLE IF NOT EXISTS subtasks ( id SERIAL NOT NULL, contest_id INT REFERENCES contests ON DELETE CASCADE, testgroup_id INT REFERENCES testgroups ON DELETE CASCADE, task_id INT REFERENCES tasks ON DELETE CASCADE, UNIQUE (contest_id,testgroup_id), PRIMARY KEY (id) ); CREATE INDEX ON subtasks USING BTREE (id); CREATE INDEX ON subtasks USING BTREE (contest_id); CREATE INDEX ON subtasks USING BTREE (testgroup_id); CREATE TABLE IF NOT EXISTS participants ( id serial NOT NULL, user_id INT NOT NULL, contest_id INT REFERENCES contests ON DELETE CASCADE, name varchar(200) NOT NULL, UNIQUE (user_id,contest_id), PRIMARY KEY (id) ); CREATE INDEX ON participants USING BTREE (id); CREATE INDEX ON participants USING BTREE (user_id); CREATE INDEX ON participants USING BTREE (contest_id); CREATE TABLE IF NOT EXISTS solutions ( id serial NOT NULL, participant_id INT REFERENCES participants ON DELETE CASCADE, task_id INT REFERENCES problems ON DELETE CASCADE, -- language_id INT NOT NULL REFERENCES languages ON DELETE CASCADE, solution_hash CHAR(128) NOT NULL, result INT NOT NULL, score INT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), PRIMARY KEY (id) ); CREATE INDEX ON solutions USING BTREE (id); -- CREATE INDEX ON solutions USING BTREE (id,participant_id,task_id,language_id); FIXME CREATE TABLE IF NOT EXISTS tests ( id serial NOT NULL, --problem_id INT NOT NULL, testgroup_id INT REFERENCES testgroups ON DELETE CASCADE, PRIMARY KEY (id) ); CREATE INDEX ON tests USING BTREE (id); CREATE INDEX ON tests USING BTREE (testgroup_id); CREATE TABLE IF NOT EXISTS subtaskruns ( id serial NOT NULL, subtask_id INT REFERENCES subtasks ON DELETE CASCADE, solution_id INT REFERENCES solutions ON DELETE CASCADE, result INT NOT NULL, score INT NOT NULL, UNIQUE (subtask_id,solution_id), PRIMARY KEY (id) ); CREATE INDEX ON subtaskruns USING BTREE (id); CREATE INDEX ON subtaskruns USING BTREE (result); CREATE INDEX ON subtaskruns USING BTREE (solution_id); CREATE TABLE IF NOT EXISTS testruns ( id serial NOT NULL, test_id INT REFERENCES tests ON DELETE CASCADE, --solution_id INT REFERENCES solutions ON DELETE CASCADE, subtaskrun_id INT REFERENCES subtaskruns ON DELETE CASCADE, result INT NOT NULL, PRIMARY KEY (id) ); CREATE INDEX ON testruns USING BTREE (id); CREATE INDEX ON testruns USING BTREE (result); CREATE INDEX ON testruns USING BTREE (subtaskrun_id); CREATE TABLE IF NOT EXISTS participant_subtask ( participant_id INT REFERENCES participants ON DELETE CASCADE, subtask_id INT REFERENCES subtasks ON DELETE CASCADE, --result INT NOT NULL, best_score INT NOT NULL ); CREATE TABLE IF NOT EXISTS participant_task ( participant_id INT REFERENCES participants ON DELETE CASCADE, task_id INT REFERENCES tasks ON DELETE CASCADE, --result INT NOT NULL, best_score INT NOT NULL, penalty INT NOT NULL ); CREATE TABLE IF NOT EXISTS users ( user_id INT NOT NULL, role INT NOT NULL, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), CHECK ( role BETWEEN 0 AND 3), PRIMARY KEY (user_id) ); CREATE FUNCTION on_new_participant() RETURNS TRIGGER AS $$ BEGIN --RAISE NOTICE 'NEW.ID:%, NEW.contest_id:%', NEW.id,NEW.contest_id; INSERT INTO participant_task (participant_id,task_id,best_score,penalty) SELECT NEW.id,id,0,0 FROM tasks WHERE contest_id=NEW.contest_id; INSERT INTO participant_subtask (participant_id,subtask_id,best_score) SELECT NEW.id,id,0 FROM subtasks WHERE contest_id=NEW.contest_id; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER new_participant_trg AFTER INSERT ON participants FOR EACH ROW EXECUTE FUNCTION on_new_participant(); CREATE FUNCTION on_new_task() RETURNS TRIGGER AS $$ BEGIN INSERT INTO participant_task (participant_id,task_id,best_score,penalty) SELECT id,NEW.id,0,0 FROM participants WHERE contest_id=NEW.contest_id; INSERT INTO subtasks(contest_id,testgroup_id,task_id) SELECT NEW.contest_id,id,NEW.id FROM testgroups WHERE problem_id = NEW.problem_id; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER new_task_trg AFTER INSERT ON tasks FOR EACH ROW EXECUTE FUNCTION on_new_task(); CREATE FUNCTION on_new_subtask() RETURNS TRIGGER AS $$ BEGIN INSERT INTO participant_subtask (participant_id,subtask_id,best_score) SELECT id,NEW.id,0 FROM participants WHERE contest_id=NEW.contest_id; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER new_subtask_trg AFTER INSERT ON subtasks FOR EACH ROW EXECUTE FUNCTION on_new_subtask(); CREATE FUNCTION on_new_solution() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN INSERT INTO subtaskruns (subtask_id,solution_id,result,score) (SELECT id,NEW.id,0,0 FROM subtasks WHERE task_id = NEW.task_id); --INSERT INTO testruns (test_id,subtaskrun_id,result) (SELECT id,str.id,0 FROM tests WHERE testgroup_id IN (SELECT testgroup_id FROM subtasks WHERE id IN (SELECT subtask_id FROM subtaskruns AS str WHERE solution_id=NEW.id))); RETURN NEW; END; $$; CREATE TRIGGER on_new_solution_trg AFTER INSERT ON solutions FOR EACH ROW EXECUTE FUNCTION on_new_solution(); CREATE FUNCTION on_new_subtaskrun() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN INSERT INTO testruns (test_id,subtaskrun_id,result) (SELECT id,NEW.id,0 FROM tests WHERE testgroup_id IN (SELECT testgroup_id FROM subtasks WHERE id=NEW.subtask_id)); RETURN NEW; END; $$; CREATE TRIGGER on_new_subtaskrun_trg AFTER INSERT ON subtaskruns FOR EACH ROW EXECUTE FUNCTION on_new_subtaskrun(); CREATE FUNCTION updated_at_update() RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$; --CREATE TRIGGER languages_upd_trg BEFORE UPDATE ON languages FOR EACH ROW EXECUTE FUNCTION updated_at_update(); CREATE TRIGGER problems_upd_trg BEFORE UPDATE ON problems FOR EACH ROW EXECUTE FUNCTION updated_at_update(); CREATE TRIGGER contests_upd_trg BEFORE UPDATE ON contests FOR EACH ROW EXECUTE FUNCTION updated_at_update(); CREATE TRIGGER users_upd_trg BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION updated_at_update(); -- +goose StatementEnd -- +goose Down -- +goose StatementBegin DROP FUNCTION IF EXISTS updated_at_update CASCADE; DROP FUNCTION IF EXISTS on_new_participant CASCADE; DROP FUNCTION IF EXISTS on_new_task CASCADE; DROP FUNCTION IF EXISTS on_new_subtask CASCADE; DROP FUNCTION IF EXISTS on_new_solution CASCADE; DROP FUNCTION IF EXISTS on_new_subtaskrun CASCADE; DROP TABLE IF EXISTS tests CASCADE; DROP TABLE IF EXISTS solutions CASCADE; --DROP TABLE IF EXISTS languages CASCADE; DROP TABLE IF EXISTS testgroups CASCADE; DROP TABLE IF EXISTS testruns CASCADE; DROP TABLE IF EXISTS subtaskruns CASCADE; DROP TABLE IF EXISTS problems CASCADE; DROP TABLE IF EXISTS contests CASCADE; DROP TABLE IF EXISTS tasks CASCADE; DROP TABLE IF EXISTS subtasks CASCADE; DROP TABLE IF EXISTS participants CASCADE; DROP TABLE IF EXISTS participant_task CASCADE; DROP TABLE IF EXISTS participant_subtask CASCADE; DROP TABLE IF EXISTS users CASCADE; -- +goose StatementEnd