improvements
This commit is contained in:
@@ -4,7 +4,9 @@ CREATE TYPE STAT AS ENUM ('waiting', 'p1turn', 'p2turn');
|
||||
CREATE TABLE IF NOT EXISTS players (
|
||||
id CHAR(16) PRIMARY KEY,
|
||||
board CHAR(10) [10],
|
||||
room_code CHAR(4) NOT NULL
|
||||
room_code CHAR(4) NOT NULL,
|
||||
abandoned BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
time TIMESTAMP DEFAULT NOW() NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS rooms (
|
||||
@@ -24,12 +26,6 @@ CREATE TABLE IF NOT EXISTS rooms (
|
||||
)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS abandoned_players (
|
||||
time TIMESTAMP PRIMARY KEY,
|
||||
id CHAR(16) NOT NULL,
|
||||
CONSTRAINT fk_player_id FOREIGN KEY (id) REFERENCES players (id) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
ALTER TABLE players
|
||||
ADD CONSTRAINT fk_room_code FOREIGN KEY (room_code) REFERENCES rooms (code) ON DELETE
|
||||
SET NULL;
|
||||
@@ -40,22 +36,5 @@ SET NULL ON UPDATE CASCADE,
|
||||
ADD CONSTRAINT fk_player2 FOREIGN KEY (player2_id) REFERENCES players (id) ON DELETE
|
||||
SET NULL ON UPDATE CASCADE;
|
||||
|
||||
-- delete room if both players are null
|
||||
CREATE OR REPLACE FUNCTION delete_room() RETURNS TRIGGER AS $$ BEGIN IF (
|
||||
SELECT player1_id IS NULL
|
||||
AND player2_id IS NULL
|
||||
FROM rooms
|
||||
WHERE code = OLD.room_code
|
||||
) THEN
|
||||
DELETE FROM rooms
|
||||
WHERE code = OLD.room_code;
|
||||
END IF;
|
||||
RETURN OLD;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER delete_room_trigger
|
||||
AFTER DELETE ON players FOR EACH ROW EXECUTE FUNCTION delete_room();
|
||||
|
||||
CREATE INDEX idx_player_room_code ON players (room_code);
|
||||
CREATE INDEX idx_room_status ON rooms (stat);
|
||||
CREATE INDEX idx_room_status ON players (abandoned);
|
39
migrations/0002_triggers.sql
Normal file
39
migrations/0002_triggers.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- delete room if both players are null
|
||||
CREATE OR REPLACE FUNCTION delete_room() RETURNS TRIGGER AS $$ BEGIN IF (
|
||||
SELECT player1_id IS NULL
|
||||
AND player2_id IS NULL
|
||||
FROM rooms
|
||||
WHERE code = OLD.room_code
|
||||
) THEN
|
||||
DELETE FROM rooms
|
||||
WHERE code = OLD.room_code;
|
||||
END IF;
|
||||
RETURN OLD;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER delete_room_trigger
|
||||
AFTER DELETE ON players FOR EACH ROW EXECUTE FUNCTION delete_room();
|
||||
|
||||
|
||||
-- retain only 1000 recent abandoned players according to timestamp
|
||||
CREATE OR REPLACE FUNCTION delete_player() RETURNS TRIGGER AS $$ BEGIN IF (
|
||||
SELECT COUNT(*)
|
||||
FROM players
|
||||
WHERE abandoned = TRUE
|
||||
) > 10000 THEN
|
||||
DELETE FROM players
|
||||
WHERE id IN (
|
||||
SELECT id
|
||||
FROM players
|
||||
WHERE abandoned = TRUE
|
||||
ORDER BY time DESC OFFSET 10000
|
||||
);
|
||||
END IF;
|
||||
RETURN OLD;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER delete_player_trigger
|
||||
AFTER
|
||||
INSERT ON players FOR EACH ROW EXECUTE FUNCTION delete_player();
|
Reference in New Issue
Block a user