ms-tester/migrations/20240727123308_initial.sql
2024-08-14 14:04:30 +03:00

183 lines
4.6 KiB
PL/PgSQL

-- +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 FUNCTION lng_upd_trg_fn() RETURNS TRIGGER
LANGUAGE plpgsql AS
$$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$;
CREATE TRIGGER lng_upd_trg
BEFORE UPDATE
ON languages
FOR EACH ROW
EXECUTE PROCEDURE lng_upd_trg_fn();
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,
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,
PRIMARY KEY(id)
);
CREATE INDEX ON contests USING BTREE (id);
CREATE TABLE IF NOT EXISTS contest_problem
(
contest_id INT REFERENCES contests ON DELETE CASCADE,
problem_id INT REFERENCES problems ON DELETE CASCADE,
position_name VARCHAR(10) NOT NULL, -- problem name like: A,B,A1,etc
UNIQUE (contest_id,problem_id)
);
CREATE INDEX ON contest_problem USING BTREE (contest_id);
CREATE INDEX ON contest_problem USING BTREE (problem_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,
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 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,
language_id INT REFERENCES languages ON DELETE CASCADE,
contest_id INT NOT NULL,
solution_hash CHAR(128) NOT NULL,
result 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,problem_id,language_id,contest_id);
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 testruns
(
id serial NOT NULL,
test_id INT REFERENCES tests ON DELETE CASCADE,
solution_id INT REFERENCES solutions 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 (solution_id);
CREATE TABLE IF NOT EXISTS participant_problem
(
participand_id INT REFERENCES participants ON DELETE CASCADE,
problem_id INT REFERENCES problems ON DELETE CASCADE,
result INT NOT NULL,
best_score INT NOT NULL
);
-- TODO: automatic creating & deleting entries on creating & deleting users & problems to contest
-- +goose StatementEnd
-- +goose Down
DROP FUNCTION IF EXISTS lng_upd_trg_fn 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 problems CASCADE;
DROP TABLE IF EXISTS contests CASCADE;
DROP TABLE IF EXISTS contest_problem CASCADE;
DROP TABLE IF EXISTS participants CASCADE;
DROP TABLE IF EXISTS participant_problem CASCADE;