diff --git a/db/10-users.sql b/db/10-users.sql index dc0aef7..7774265 100644 --- a/db/10-users.sql +++ b/db/10-users.sql @@ -2,7 +2,5 @@ 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) ); diff --git a/db/50-follows.sql b/db/50-follows.sql new file mode 100644 index 0000000..c511c43 --- /dev/null +++ b/db/50-follows.sql @@ -0,0 +1,4 @@ +CREATE TABLE follows ( + userid integer, + PRIMARY KEY (userid) +) diff --git a/db/50-subscriptions.sql b/db/50-subscriptions.sql new file mode 100644 index 0000000..4271623 --- /dev/null +++ b/db/50-subscriptions.sql @@ -0,0 +1,4 @@ +CREATE TABLE subscriptions ( + userid integer, + PRIMARY KEY (userid) +) diff --git a/db/90-views.sql b/db/90-views.sql index e274069..deb6aaa 100644 --- a/db/90-views.sql +++ b/db/90-views.sql @@ -40,11 +40,11 @@ CREATE OR REPLACE VIEW vote_score_vw AS COUNT(votes.requesturl) AS count, COALESCE( SUM(CASE - WHEN users.isfollower = FALSE AND users.issubscriber = FALSE + WHEN follows.userid IS NULL AND subscriptions.userid IS NULL THEN votepoints.normaluservotepoints - WHEN users.isfollower = TRUE AND users.issubscriber = FALSE + WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL THEN votepoints.followervotepoints - WHEN users.issubscriber = TRUE + WHEN subscriptions.userid IS NOT NULL THEN votepoints.subscribervotepoints END), 0 ) AS votescore @@ -52,6 +52,8 @@ CREATE OR REPLACE VIEW vote_score_vw AS LEFT JOIN votes ON votes.requesturl = requests.url LEFT JOIN users on votes.userid = users.userid LEFT JOIN bans ON users.userid = bans.userid + LEFT JOIN follows ON users.userid = follows.userid + LEFT JOIN subscriptions ON users.userid = subscriptions.userid CROSS JOIN votepoints WHERE bans.userid IS NULL GROUP BY url; diff --git a/db/testdata.sql b/db/testdata.sql index 83428e6..98db264 100644 --- a/db/testdata.sql +++ b/db/testdata.sql @@ -1,8 +1,16 @@ -INSERT INTO users (userid,displayName,isFollower,isSubscriber) VALUES - (001,'TestUser',false,false), - (002,'TestFollower',true,false), - (003,'TestSubscriber',true,true), - (004,'TestSubNonFollower',false,true); +INSERT INTO users (userid,displayName) VALUES + (001,'TestUser'), + (002,'TestFollower'), + (003,'TestSubscriber'), + (004,'TestSubNonFollower'); + +INSERT INTO follows (userid) VALUES + (002), + (003); + +INSERT INTO subscriptions (userid) VALUES + (003), + (004); CALL add_request('https://www.youtube.com/watch?v=dQw4w9WgXcQ',001); CALL add_request('https://www.youtube.com/watch?v=C5oeWHngDS4',002); diff --git a/db/upgrade/v0.4-0.5.sql b/db/upgrade/v0.4-0.5.sql new file mode 100644 index 0000000..058eef6 --- /dev/null +++ b/db/upgrade/v0.4-0.5.sql @@ -0,0 +1,49 @@ +BEGIN; + +--UPDATE version SET minor = 5; + +CREATE OR REPLACE PROCEDURE update_vote_points(normaluser int, follower int, subscriber int) + LANGUAGE SQL + AS $$ + UPDATE config SET normaluservotepoints = normaluser, + followervotepoints = follower, subscribervotepoints = subscriber; + CALL update_scores(); + $$; + +CREATE TABLE follows ( + userid integer, + PRIMARY KEY (userid) +); + +CREATE TABLE subscriptions ( + userid integer, + PRIMARY KEY (userid) +); + +CREATE OR REPLACE VIEW vote_score_vw AS + WITH votepoints AS (SELECT normaluservotepoints, followervotepoints, subscribervotepoints FROM config) + SELECT requests.url AS url, + COUNT(votes.requesturl) AS count, + COALESCE( + SUM(CASE + WHEN follows.userid IS NULL AND subscriptions.userid IS NULL + THEN votepoints.normaluservotepoints + WHEN follows.userid IS NOT NULL AND subscriptions.userid IS NULL + THEN votepoints.followervotepoints + WHEN subscriptions.userid IS NOT NULL + THEN votepoints.subscribervotepoints + END), 0 + ) AS votescore + FROM requests + LEFT JOIN votes ON votes.requesturl = requests.url + LEFT JOIN users on votes.userid = users.userid + LEFT JOIN bans ON users.userid = bans.userid + LEFT JOIN follows ON users.userid = follows.userid + LEFT JOIN subscriptions ON users.userid = subscriptions.userid + CROSS JOIN votepoints + WHERE bans.userid IS NULL + GROUP BY url; + +ALTER TABLE users DROP COLUMN isfollower, DROP COLUMN issubscriber; + +COMMIT;