Redesign database and implement voting
This commit is contained in:
parent
a0b65c7d5b
commit
80e9bc1bde
16 changed files with 376 additions and 41 deletions
|
@ -1,10 +1,11 @@
|
|||
CREATE TABLE states (
|
||||
state varchar UNIQUE NOT NULL,
|
||||
active bool NOT NULL DEFAULT TRUE, -- Whether request can be considered "active"
|
||||
PRIMARY KEY(state)
|
||||
);
|
||||
|
||||
INSERT INTO states (state) VALUES
|
||||
('Requested'),
|
||||
('Rejected'),
|
||||
('Accepted'),
|
||||
('Learned');
|
||||
INSERT INTO states (state,active) VALUES
|
||||
('Requested',TRUE),
|
||||
('Rejected',FALSE),
|
||||
('Accepted',TRUE),
|
||||
('Learned',FALSE);
|
||||
|
|
10
db/05-config.sql
Normal file
10
db/05-config.sql
Normal file
|
@ -0,0 +1,10 @@
|
|||
CREATE TABLE config (
|
||||
rowlock bool DEFAULT TRUE UNIQUE NOT NULL CHECK (rowlock = TRUE),
|
||||
normaluservotepoints int NOT NULL,
|
||||
followervotepoints int NOT NULL,
|
||||
subscribervotepoints int NOT NULL,
|
||||
PRIMARY KEY (rowLock)
|
||||
);
|
||||
|
||||
INSERT INTO config (normalUserVotePoints,followerVotePoints,subscriberVotePoints)
|
||||
VALUES (10,50,100);
|
|
@ -1,9 +0,0 @@
|
|||
CREATE TABLE requests (
|
||||
id int GENERATED ALWAYS AS IDENTITY,
|
||||
url varchar UNIQUE,
|
||||
requester varchar NOT NULL,
|
||||
score int DEFAULT 0,
|
||||
state varchar NOT NULL DEFAULT 'Requested',
|
||||
PRIMARY KEY(id),
|
||||
FOREIGN KEY (state) REFERENCES states(state)
|
||||
);
|
8
db/10-users.sql
Normal file
8
db/10-users.sql
Normal file
|
@ -0,0 +1,8 @@
|
|||
CREATE TABLE users (
|
||||
userId int NOT NULL,
|
||||
displayName varchar NOT NULL,
|
||||
imageUrl varchar,
|
||||
isFollower boolean NOT NULL DEFAULT FALSE,
|
||||
isSubscriber boolean NOT NULL DEFAULT FALSE,
|
||||
PRIMARY KEY (userId)
|
||||
);
|
9
db/20-requests.sql
Normal file
9
db/20-requests.sql
Normal file
|
@ -0,0 +1,9 @@
|
|||
CREATE TABLE requests (
|
||||
url varchar NOT NULL UNIQUE,
|
||||
requester int NOT NULL,
|
||||
state varchar NOT NULL DEFAULT 'Requested',
|
||||
reqTimestamp timestamptz NOT NULL DEFAULT NOW(),
|
||||
PRIMARY KEY (url),
|
||||
FOREIGN KEY (requester) REFERENCES users(userid),
|
||||
FOREIGN KEY (state) REFERENCES states(state)
|
||||
);
|
7
db/30-votes.sql
Normal file
7
db/30-votes.sql
Normal file
|
@ -0,0 +1,7 @@
|
|||
CREATE TABLE votes (
|
||||
requestUrl varchar,
|
||||
userId int,
|
||||
PRIMARY KEY (requestUrl,userId),
|
||||
FOREIGN KEY (requestUrl) REFERENCES requests(url),
|
||||
FOREIGN KEY (userId) REFERENCES users(userId)
|
||||
);
|
7
db/40-scores.sql
Normal file
7
db/40-scores.sql
Normal file
|
@ -0,0 +1,7 @@
|
|||
CREATE TABLE scores (
|
||||
url varchar,
|
||||
baseScore int NOT NULL DEFAULT 0,
|
||||
score int NOT NULL DEFAULT 0,
|
||||
PRIMARY KEY (url),
|
||||
FOREIGN KEY (url) REFERENCES requests(url)
|
||||
);
|
114
db/90-views.sql
114
db/90-views.sql
|
@ -1,5 +1,111 @@
|
|||
CREATE VIEW requests_vw AS
|
||||
SELECT * FROM requests WHERE state = 'Requested' ORDER BY score DESC, id ASC;
|
||||
CREATE OR REPLACE FUNCTION get_requests()
|
||||
RETURNS TABLE (
|
||||
url varchar,
|
||||
requester varchar,
|
||||
state varchar,
|
||||
score int,
|
||||
reqTimestamp timestamptz
|
||||
)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT url,displayName AS requester,state,score,reqTimestamp FROM requests
|
||||
JOIN scores USING (url)
|
||||
JOIN users ON requests.requester = users.userid
|
||||
WHERE state IN (SELECT state FROM states WHERE active)
|
||||
ORDER BY score DESC, reqTimestamp ASC;
|
||||
$$;
|
||||
|
||||
CREATE VIEW requests_all_vw AS
|
||||
SELECT * FROM requests ORDER BY score DESC, id ASC;
|
||||
CREATE OR REPLACE FUNCTION get_requests_all()
|
||||
RETURNS TABLE (
|
||||
url varchar,
|
||||
requester varchar,
|
||||
state varchar,
|
||||
score int,
|
||||
reqTimestamp timestamptz
|
||||
)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT url,displayName AS requester,state,score,reqTimestamp FROM requests
|
||||
JOIN scores USING (url)
|
||||
JOIN users ON requests.requester = users.userid
|
||||
ORDER BY score DESC, reqTimestamp ASC;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
|
||||
RETURNS TABLE (
|
||||
url varchar,
|
||||
requester varchar,
|
||||
state varchar,
|
||||
score int,
|
||||
reqTimestamp timestamptz,
|
||||
voted bool
|
||||
)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT url,displayName AS requester,state,score,reqTimestamp,
|
||||
(CASE WHEN votes.userid IS NULL THEN FALSE ELSE TRUE END) AS voted
|
||||
FROM requests
|
||||
JOIN scores USING (url)
|
||||
JOIN users ON requests.requester = users.userid
|
||||
LEFT JOIN votes ON (requests.url = votes.requesturl AND votes.userid = votinguserid)
|
||||
WHERE state IN (SELECT state FROM states WHERE active)
|
||||
ORDER BY score DESC, reqTimestamp ASC;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_requests_all_voted(votinguserid int)
|
||||
RETURNS TABLE (
|
||||
url varchar,
|
||||
requester varchar,
|
||||
state varchar,
|
||||
score int,
|
||||
reqTimestamp timestamptz,
|
||||
voted bool
|
||||
)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT url,displayName AS requester,state,score,reqTimestamp,
|
||||
(CASE WHEN votes.userid IS NULL THEN FALSE ELSE TRUE END) AS voted
|
||||
FROM requests
|
||||
JOIN scores USING (url)
|
||||
JOIN users ON requests.requester = users.userid
|
||||
LEFT JOIN votes ON (requests.url = votes.requesturl AND votes.userid = votinguserid)
|
||||
ORDER BY score DESC, reqTimestamp ASC;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Views to determine the score added by votes from different classes of users.
|
||||
In order for songs with no votes to show up in this view (and thus have their
|
||||
scores properly calculated), the query must be JOINed to requests, the URL must
|
||||
be selected as requests.url rather than votes.requesturl (which is null in the
|
||||
case of no votes), and users.is{follower,subscriber} must be COALESCEd to FALSE
|
||||
as in the case of no votes, user.* will be NULL.
|
||||
*/
|
||||
|
||||
CREATE OR REPLACE VIEW vote_score_normal_vw AS
|
||||
SELECT requests.url,COUNT(votes.requesturl),(COUNT(votes.requesturl) * (SELECT normaluservotepoints FROM config)) AS votescore FROM requests
|
||||
LEFT JOIN votes ON votes.requesturl = requests.url
|
||||
LEFT JOIN users on votes.userid = users.userid
|
||||
WHERE COALESCE(users.isfollower,FALSE) = FALSE AND COALESCE(users.issubscriber,FALSE) = FALSE
|
||||
GROUP BY requests.url;
|
||||
|
||||
CREATE OR REPLACE VIEW vote_score_follower_vw AS
|
||||
SELECT requests.url,COUNT(votes.requesturl),(COUNT(votes.requesturl) * (SELECT followervotepoints FROM config)) AS votescore FROM requests
|
||||
LEFT JOIN votes ON votes.requesturl = requests.url
|
||||
LEFT JOIN users on votes.userid = users.userid
|
||||
WHERE COALESCE(users.isfollower,FALSE) = TRUE AND COALESCE(users.issubscriber,FALSE) = FALSE
|
||||
GROUP BY requests.url;
|
||||
|
||||
CREATE OR REPLACE VIEW vote_score_subscriber_vw AS
|
||||
SELECT requests.url,COUNT(votes.requesturl),(COUNT(votes.requesturl) * (SELECT subscribervotepoints FROM config)) AS votescore FROM requests
|
||||
LEFT JOIN votes ON votes.requesturl = requests.url
|
||||
LEFT JOIN users on votes.userid = users.userid
|
||||
WHERE COALESCE(users.issubscriber,FALSE) = TRUE
|
||||
GROUP BY requests.url;
|
||||
|
||||
CREATE OR REPLACE VIEW vote_score_all_vw AS
|
||||
SELECT url,SUM(count) AS count, SUM(votescore) AS votescore FROM
|
||||
(SELECT * FROM vote_score_normal_vw
|
||||
UNION ALL SELECT * FROM vote_score_follower_vw
|
||||
UNION ALL SELECT * FROM vote_score_subscriber_vw
|
||||
) AS union_vote_score
|
||||
GROUP BY url;
|
||||
|
|
30
db/95-procedures.sql
Normal file
30
db/95-procedures.sql
Normal file
|
@ -0,0 +1,30 @@
|
|||
CREATE OR REPLACE PROCEDURE update_scores()
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
UPDATE scores SET score = basescore + votescore
|
||||
FROM vote_score_all_vw
|
||||
WHERE scores.url = vote_score_all_vw.url;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE add_request(url varchar,requester int)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
INSERT INTO requests (url,requester) VALUES (url,requester);
|
||||
INSERT INTO scores (url) VALUES (url);
|
||||
INSERT INTO votes (requesturl,userid) VALUES (url,requester);
|
||||
CALL update_scores();
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE add_vote(url varchar,voteuser int)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
INSERT INTO votes (requesturl,userid) VALUES (url,voteuser);
|
||||
CALL update_scores();
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE delete_vote(url varchar,voteuser int)
|
||||
LANGUAGE SQL
|
||||
AS $$
|
||||
DELETE FROM votes WHERE requesturl = url AND userid = voteuser;
|
||||
CALL update_scores();
|
||||
$$;
|
|
@ -1,5 +1,22 @@
|
|||
INSERT INTO requests (url,requester,score,state) VALUES
|
||||
('https://www.youtube.com/watch?v=dQw4w9WgXcQ','virtualdxs',0,'Rejected'),
|
||||
('https://www.youtube.com/watch?v=C5oeWHngDS4','virtualdxs',500,'Requested'),
|
||||
('https://www.youtube.com/watch?v=vXaJGBLRA_o','virtualdxs',0,'Requested');
|
||||
INSERT INTO users (userId,displayName,isFollower,isSubscriber) VALUES
|
||||
(001,'user',false,false),
|
||||
(002,'follower',true,false),
|
||||
(003,'subscriber',true,true),
|
||||
(004,'subnonfollower',false,true);
|
||||
|
||||
/* INSERT INTO requests (url,requester,state) VALUES
|
||||
('https://www.youtube.com/watch?v=dQw4w9WgXcQ',001,'Rejected'),
|
||||
('https://www.youtube.com/watch?v=C5oeWHngDS4',002,'Requested'),
|
||||
('https://www.youtube.com/watch?v=vXaJGBLRA_o',003,'Requested'); */
|
||||
|
||||
CALL add_request('https://www.youtube.com/watch?v=dQw4w9WgXcQ',001);
|
||||
CALL add_request('https://www.youtube.com/watch?v=C5oeWHngDS4',002);
|
||||
CALL add_request('https://www.youtube.com/watch?v=vXaJGBLRA_o',003);
|
||||
|
||||
UPDATE requests SET state = 'Rejected' WHERE url = 'https://www.youtube.com/watch?v=dQw4w9WgXcQ';
|
||||
|
||||
INSERT INTO votes (requestUrl,userid) VALUES
|
||||
('https://www.youtube.com/watch?v=C5oeWHngDS4',001),
|
||||
('https://www.youtube.com/watch?v=C5oeWHngDS4',003);
|
||||
|
||||
CALL update_scores();
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue