ms-tester/migrations/20240727123308_initial.sql

219 lines
5.8 KiB
MySQL
Raw Normal View History

2024-07-27 09:27:14 +00:00
-- +goose Up
-- +goose StatementBegin
CREATE TABLE IF NOT EXISTS languages
(
id serial NOT NULL,
name VARCHAR(60) NOT NULL,
2024-08-14 08:35:36 +00:00
build_file_hash CHAR(128) NULL,
execute_file_hash CHAR(128) NULL,
2024-07-27 09:27:14 +00:00
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
2024-07-27 09:42:05 +00:00
PRIMARY KEY (id)
2024-07-27 09:27:14 +00:00
);
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
2024-08-14 15:57:59 +00:00
EXECUTE FUNCTION lng_upd_trg_fn();
2024-07-27 09:27:14 +00:00
2024-08-14 08:35:36 +00:00
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);
2024-08-14 11:04:30 +00:00
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,
2024-08-14 15:57:59 +00:00
position INT NOT NULL,
2024-08-14 11:04:30 +00:00
position_name VARCHAR(10) NOT NULL, -- problem name like: A,B,A1,etc
2024-08-14 15:57:59 +00:00
UNIQUE (contest_id,problem_id),
UNIQUE (contest_id,position),
UNIQUE (contest_id,position_name)
2024-08-14 11:04:30 +00:00
);
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,
2024-08-14 15:57:59 +00:00
UNIQUE (user_id,contest_id),
2024-08-14 11:04:30 +00:00
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);
2024-08-14 08:35:36 +00:00
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);
2024-07-27 09:27:14 +00:00
CREATE TABLE IF NOT EXISTS solutions
(
2024-08-14 11:04:30 +00:00
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(),
2024-07-27 09:27:14 +00:00
2024-07-27 09:42:05 +00:00
PRIMARY KEY (id)
2024-07-27 09:27:14 +00:00
);
2024-07-27 09:42:05 +00:00
CREATE INDEX ON solutions USING BTREE (id);
2024-08-14 11:04:30 +00:00
CREATE INDEX ON solutions USING BTREE (id,participant_id,problem_id,language_id,contest_id);
2024-08-14 08:35:36 +00:00
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);
2024-08-14 11:04:30 +00:00
CREATE TABLE IF NOT EXISTS participant_problem
2024-08-14 08:35:36 +00:00
(
2024-08-14 15:57:59 +00:00
participant_id INT REFERENCES participants ON DELETE CASCADE,
2024-08-14 11:04:30 +00:00
problem_id INT REFERENCES problems ON DELETE CASCADE,
result INT NOT NULL,
2024-08-14 15:57:59 +00:00
best_score INT NOT NULL,
penalty INT NOT NULL
2024-08-14 08:35:36 +00:00
);
2024-08-14 15:57:59 +00:00
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;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER fill_participant_result_trg
AFTER INSERT
ON participants
FOR EACH ROW
EXECUTE FUNCTION fill_participant_result();
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;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER fill_problem_result_trg
AFTER INSERT
ON contest_problem
FOR EACH ROW
EXECUTE FUNCTION fill_problem_result();
2024-08-14 11:04:30 +00:00
-- TODO: automatic creating & deleting entries on creating & deleting users & problems to contest
2024-07-27 09:27:14 +00:00
-- +goose StatementEnd
-- +goose Down
2024-08-14 08:35:36 +00:00
DROP FUNCTION IF EXISTS lng_upd_trg_fn CASCADE;
2024-08-14 15:57:59 +00:00
DROP FUNCTION IF EXISTS fill_participant_result CASCADE;
DROP FUNCTION IF EXISTS fill_problem_result CASCADE;
2024-08-14 08:35:36 +00:00
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;
2024-08-14 11:04:30 +00:00
DROP TABLE IF EXISTS contest_problem CASCADE;
DROP TABLE IF EXISTS participants CASCADE;
DROP TABLE IF EXISTS participant_problem CASCADE;