Files
qv/sql/init.sql

74 lines
2.3 KiB
MySQL
Raw Normal View History

CREATE TABLE elections (
2024-12-26 16:51:16 +01:00
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
tokens INTEGER NOT NULL,
are_voters_known INTEGER NOT NULL,
max_voters INTEGER, -- mandatory when voters are known
2024-12-27 12:45:09 +01:00
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
expires_at DATETIME NOT NULL,
CHECK (are_voters_known = 0 OR (are_voters_known = 1 AND max_voters IS NOT NULL AND max_voters >= 1))
2024-12-26 16:51:16 +01:00
);
CREATE TRIGGER prevent_created_at_update_election
BEFORE UPDATE OF created_at ON elections
BEGIN
SELECT RAISE(FAIL, 'created_at column is read-only');
END;
2024-12-26 16:51:16 +01:00
CREATE TABLE choices (
text TEXT NOT NULL,
election_id INTEGER NOT NULL,
PRIMARY KEY (text, election_id),
FOREIGN KEY (election_id) REFERENCES elections (id)
2024-12-26 16:51:16 +01:00
);
CREATE TABLE voters (
identity TEXT NOT NULL, -- when voters are known, passcodes will be pre-generated
2024-12-26 16:51:16 +01:00
election_id INTEGER NOT NULL,
PRIMARY KEY (identity, election_id),
FOREIGN KEY (election_id) REFERENCES elections (id)
2024-12-26 16:51:16 +01:00
);
CREATE TRIGGER enforce_max_voters
BEFORE INSERT ON voters
WHEN EXISTS (
SELECT 1
FROM elections e
WHERE e.id = NEW.election_id
AND e.max_voters IS NOT NULL
)
BEGIN
SELECT CASE
WHEN (
SELECT COUNT(*)
FROM voters v
WHERE v.election_id = NEW.election_id
) >= (
SELECT max_voters
FROM elections
WHERE id = NEW.election_id
)
THEN RAISE(FAIL, 'Maximum number of voters reached for this election')
END;
END;
2024-12-26 16:51:16 +01:00
CREATE TABLE votes (
voter_identity TEXT NOT NULL,
2024-12-26 16:51:16 +01:00
election_id INTEGER NOT NULL,
2024-12-27 12:45:09 +01:00
choice_text TEXT NOT NULL,
tokens INTEGER NOT NULL,
calculated_vote_count GENERATED ALWAYS AS (floor(sqrt(tokens))) VIRTUAL,
2024-12-27 12:45:09 +01:00
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (voter_identity, choice_text),
FOREIGN KEY (voter_identity, election_id) REFERENCES voters (identity, election_id),
FOREIGN KEY (choice_text, election_id) REFERENCES choices (text, election_id),
CHECK (tokens IS NULL OR tokens >= 0)
2024-12-26 16:51:16 +01:00
);
CREATE TRIGGER prevent_created_at_update_votes
BEFORE UPDATE OF created_at ON votes
BEGIN
SELECT RAISE(FAIL, 'created_at column is read-only');
END;
2024-12-26 16:51:16 +01:00
PRAGMA foreign_keys = ON; -- run after opening the connection so foreign key constraints are checked