diff --git a/migrations/20240727123308_initial.sql b/migrations/20240727123308_initial.sql index 1bed51f..1c81572 100644 --- a/migrations/20240727123308_initial.sql +++ b/migrations/20240727123308_initial.sql @@ -22,11 +22,7 @@ BEGIN END; $$; -CREATE TRIGGER lng_upd_trg - BEFORE UPDATE - ON languages - FOR EACH ROW -EXECUTE FUNCTION lng_upd_trg_fn(); +CREATE TRIGGER lng_upd_trg BEFORE UPDATE ON languages FOR EACH ROW EXECUTE FUNCTION lng_upd_trg_fn(); @@ -60,19 +56,54 @@ CREATE INDEX ON contests USING BTREE (id); -CREATE TABLE IF NOT EXISTS contest_problem +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) + UNIQUE (contest_id,position_name), + PRIMARY KEY (id) ); -CREATE INDEX ON contest_problem USING BTREE (contest_id); -CREATE INDEX ON contest_problem USING BTREE (problem_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); @@ -95,26 +126,12 @@ CREATE INDEX ON participants USING BTREE (contest_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 solutions ( id serial NOT NULL, participant_id INT REFERENCES participants ON DELETE CASCADE, - problem_id INT REFERENCES problems ON DELETE CASCADE, + --problem_id INT REFERENCES problems ON DELETE CASCADE, + task_id INT REFERENCES problems ON DELETE CASCADE, language_id INT REFERENCES languages ON DELETE CASCADE, contest_id INT NOT NULL, solution_hash CHAR(128) NOT NULL, @@ -125,7 +142,7 @@ CREATE TABLE IF NOT EXISTS solutions ); CREATE INDEX ON solutions USING BTREE (id); -CREATE INDEX ON solutions USING BTREE (id,participant_id,problem_id,language_id,contest_id); +CREATE INDEX ON solutions USING BTREE (id,participant_id,task_id,language_id,contest_id); @@ -162,51 +179,61 @@ CREATE INDEX ON testruns USING BTREE (solution_id); -CREATE TABLE IF NOT EXISTS participant_problem +CREATE TABLE IF NOT EXISTS participant_subtask ( participant_id INT REFERENCES participants ON DELETE CASCADE, - problem_id INT REFERENCES problems 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 FUNCTION fill_participant_result() RETURNS TRIGGER AS -$$ -BEGIN - RAISE NOTICE 'NEW.ID:%, NEW.contest_id:%', NEW.id,NEW.contest_id; - INSERT INTO participant_problem (participant_id,problem_id,result,best_score,penalty) SELECT NEW.id,problem_id,0,0,0 FROM contest_problem WHERE contest_id=NEW.contest_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,result,best_score,penalty) SELECT NEW.id,id,0,0,0 FROM tasks WHERE contest_id=NEW.contest_id; + INSERT INTO participant_subtask (participant_id,subtask_id,result,best_score) SELECT NEW.id,id,0,0 FROM subtasks WHERE contest_id=NEW.contest_id; RETURN NEW; -END; -$$ LANGUAGE plpgsql; +END; $$ LANGUAGE plpgsql; -CREATE TRIGGER fill_participant_result_trg - AFTER INSERT - ON participants - FOR EACH ROW -EXECUTE FUNCTION fill_participant_result(); +CREATE TRIGGER new_participant_trg AFTER INSERT ON participants FOR EACH ROW EXECUTE FUNCTION on_new_participant(); -CREATE FUNCTION fill_problem_result() RETURNS TRIGGER AS -$$ -BEGIN - INSERT INTO participant_problem (participant_id,problem_id,result,best_score,penalty) SELECT id,NEW.problem_id,0,0,0 FROM participants WHERE contest_id=NEW.contest_id; +CREATE FUNCTION on_new_task() RETURNS TRIGGER AS +$$ BEGIN + INSERT INTO participant_task (participant_id,task_id,result,best_score,penalty) SELECT id,NEW.id,0,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; +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,result,best_score) SELECT id,NEW.id,0,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 TRIGGER fill_problem_result_trg - AFTER INSERT - ON contest_problem - FOR EACH ROW -EXECUTE FUNCTION fill_problem_result(); --- TODO: automatic creating & deleting entries on creating & deleting users & problems to contest -- +goose StatementEnd -- +goose Down -- +goose StatementBegin DROP FUNCTION IF EXISTS lng_upd_trg_fn CASCADE; -DROP FUNCTION IF EXISTS fill_participant_result CASCADE; -DROP FUNCTION IF EXISTS fill_problem_result 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 TABLE IF EXISTS tests CASCADE; DROP TABLE IF EXISTS solutions CASCADE; DROP TABLE IF EXISTS languages CASCADE; @@ -214,7 +241,9 @@ DROP TABLE IF EXISTS testgroups CASCADE; DROP TABLE IF EXISTS testruns CASCADE; DROP TABLE IF EXISTS problems CASCADE; DROP TABLE IF EXISTS contests CASCADE; -DROP TABLE IF EXISTS contest_problem CASCADE; +DROP TABLE IF EXISTS tasks CASCADE; +DROP TABLE IF EXISTS subtasks CASCADE; DROP TABLE IF EXISTS participants CASCADE; -DROP TABLE IF EXISTS participant_problem CASCADE; +DROP TABLE IF EXISTS participant_task CASCADE; +DROP TABLE IF EXISTS participant_subtask CASCADE; -- +goose StatementEnd diff --git a/todo.md b/todo.md index 1d2f062..12f6971 100644 --- a/todo.md +++ b/todo.md @@ -1,3 +1,4 @@ # TODO LIST: * create contest groups +* add ability to change testset