Small fixes in init.sql and create drop.sql
This commit is contained in:
66
sql/init.sql
66
sql/init.sql
@ -1,34 +1,74 @@
|
||||
CREATE TABLE election (
|
||||
CREATE TABLE elections (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
name TEXT NOT NULL,
|
||||
tokens INTEGER NOT NULL,
|
||||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
||||
is_anonymous INTEGER NOT NULL,
|
||||
max_voters INTEGER, -- mandatory when election is anonymous
|
||||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
expires_at DATETIME NOT NULL,
|
||||
CHECK (is_anonymous = 0 OR (is_anonymous = 1 AND max_voters IS NOT NULL AND max_voters >= 1))
|
||||
);
|
||||
|
||||
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;
|
||||
|
||||
CREATE TABLE choices (
|
||||
text TEXT NOT NULL,
|
||||
election_id INTEGER NOT NULL,
|
||||
PRIMARY KEY (text, election_id),
|
||||
FOREIGN KEY (election_id) REFERENCES election (id)
|
||||
FOREIGN KEY (election_id) REFERENCES elections (id)
|
||||
);
|
||||
|
||||
CREATE TABLE voters (
|
||||
passcode TEXT NOT NULL,
|
||||
identity TEXT NOT NULL, -- when election is anonymous, passcodes will be pre-generated
|
||||
election_id INTEGER NOT NULL,
|
||||
PRIMARY KEY (passcode, election_id),
|
||||
FOREIGN KEY (election_id) REFERENCES election (id)
|
||||
PRIMARY KEY (identity, election_id),
|
||||
FOREIGN KEY (election_id) REFERENCES elections (id)
|
||||
);
|
||||
|
||||
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;
|
||||
|
||||
CREATE TABLE votes (
|
||||
voter_passcode TEXT NOT NULL,
|
||||
voter_identity TEXT NOT NULL,
|
||||
election_id INTEGER NOT NULL,
|
||||
choice_text TEXT NOT NULL,
|
||||
tokens INTEGER NOT NULL,
|
||||
calculated_vote_count GENERATED ALWAYS AS (sqrt(tokens)) VIRTUAL,
|
||||
choice_text TEXT,
|
||||
tokens INTEGER,
|
||||
calculated_vote_count GENERATED ALWAYS AS (floor(sqrt(tokens))) VIRTUAL,
|
||||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (voter_passcode, choice_text),
|
||||
FOREIGN KEY (voter_passcode, election_id) REFERENCES voters (passcode, election_id),
|
||||
FOREIGN KEY (choice_text, election_id) REFERENCES choices (text, election_id)
|
||||
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)
|
||||
);
|
||||
|
||||
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;
|
||||
|
||||
PRAGMA foreign_keys = ON; -- run after opening the connection so foreign key constraints are checked
|
Reference in New Issue
Block a user