update schema

This commit is contained in:
dragonmuffin 2024-08-14 18:57:59 +03:00
parent cfad38766b
commit ad49c66978

View file

@ -26,7 +26,7 @@ CREATE TRIGGER lng_upd_trg
BEFORE UPDATE BEFORE UPDATE
ON languages ON languages
FOR EACH ROW FOR EACH ROW
EXECUTE PROCEDURE lng_upd_trg_fn(); EXECUTE FUNCTION lng_upd_trg_fn();
@ -64,8 +64,11 @@ CREATE TABLE IF NOT EXISTS contest_problem
( (
contest_id INT REFERENCES contests ON DELETE CASCADE, contest_id INT REFERENCES contests ON DELETE CASCADE,
problem_id INT REFERENCES problems 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 position_name VARCHAR(10) NOT NULL, -- problem name like: A,B,A1,etc
UNIQUE (contest_id,problem_id) UNIQUE (contest_id,problem_id),
UNIQUE (contest_id,position),
UNIQUE (contest_id,position_name)
); );
CREATE INDEX ON contest_problem USING BTREE (contest_id); CREATE INDEX ON contest_problem USING BTREE (contest_id);
@ -81,6 +84,7 @@ CREATE TABLE IF NOT EXISTS participants
contest_id INT REFERENCES contests ON DELETE CASCADE, contest_id INT REFERENCES contests ON DELETE CASCADE,
name varchar(200) NOT NULL, name varchar(200) NOT NULL,
UNIQUE (user_id,contest_id),
PRIMARY KEY (id) PRIMARY KEY (id)
); );
@ -160,16 +164,48 @@ CREATE INDEX ON testruns USING BTREE (solution_id);
CREATE TABLE IF NOT EXISTS participant_problem CREATE TABLE IF NOT EXISTS participant_problem
( (
participand_id INT REFERENCES participants ON DELETE CASCADE, participant_id INT REFERENCES participants ON DELETE CASCADE,
problem_id INT REFERENCES problems ON DELETE CASCADE, problem_id INT REFERENCES problems ON DELETE CASCADE,
result INT NOT NULL, result INT NOT NULL,
best_score 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;
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();
-- TODO: automatic creating & deleting entries on creating & deleting users & problems to contest -- TODO: automatic creating & deleting entries on creating & deleting users & problems to contest
-- +goose StatementEnd -- +goose StatementEnd
-- +goose Down -- +goose Down
DROP FUNCTION IF EXISTS lng_upd_trg_fn CASCADE; 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 TABLE IF EXISTS tests CASCADE; DROP TABLE IF EXISTS tests CASCADE;
DROP TABLE IF EXISTS solutions CASCADE; DROP TABLE IF EXISTS solutions CASCADE;
DROP TABLE IF EXISTS languages CASCADE; DROP TABLE IF EXISTS languages CASCADE;