SQL refactoring

master
Dessa Simpson 2020-09-20 17:22:07 -07:00
parent b334066f8f
commit 68f767b28d
2 changed files with 34 additions and 102 deletions

View File

@ -1,37 +1,8 @@
CREATE OR REPLACE FUNCTION get_requests()
RETURNS TABLE (
url varchar,
requester varchar,
imageUrl varchar,
state varchar,
score int,
reqTimestamp timestamptz
)
LANGUAGE SQL
AS $$
SELECT url,displayName AS requester,imageUrl,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 OR REPLACE FUNCTION get_requests_all()
RETURNS TABLE (
url varchar,
requester varchar,
imageUrl varchar,
state varchar,
score int,
reqTimestamp timestamptz
)
LANGUAGE SQL
AS $$
SELECT url,displayName AS requester,imageUrl,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 VIEW requests_vw AS
SELECT url,displayName AS requester,imageUrl,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 (
@ -45,85 +16,42 @@ CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
)
LANGUAGE SQL
AS $$
SELECT url,displayName AS requester,imageUrl,state,score,reqTimestamp,
SELECT url,requester,imageUrl,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,
imageUrl varchar,
state varchar,
score int,
reqTimestamp timestamptz,
voted bool
)
LANGUAGE SQL
AS $$
SELECT url,displayName AS requester,imageUrl,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)
FROM requests_vw
LEFT JOIN votes ON (requests_vw.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
View 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) FILTER(WHERE bans.userid IS NULL),
(COUNT(votes.requesturl) FILTER(WHERE bans.userid IS NULL) * (SELECT normaluservotepoints FROM config)) AS votescore
CREATE OR REPLACE VIEW vote_score_all_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 users.isfollower = FALSE AND users.issubscriber = FALSE
THEN votepoints.normaluservotepoints
WHEN users.isfollower = TRUE AND users.issubscriber = FALSE
THEN votepoints.followervotepoints
WHEN users.issubscriber = TRUE
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
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) FILTER(WHERE bans.userid IS NULL),
(COUNT(votes.requesturl) FILTER(WHERE bans.userid IS NULL) * (SELECT followervotepoints FROM config)) AS votescore
LEFT JOIN votes ON votes.requesturl = requests.url
LEFT JOIN users on votes.userid = users.userid
LEFT JOIN bans ON users.userid = bans.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) FILTER(WHERE bans.userid IS NULL),
(COUNT(votes.requesturl) FILTER(WHERE bans.userid IS NULL) * (SELECT subscribervotepoints FROM config)) AS votescore
LEFT JOIN votes ON votes.requesturl = requests.url
LEFT JOIN users on votes.userid = users.userid
LEFT JOIN bans ON users.userid = bans.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
CROSS JOIN votepoints
WHERE bans.userid IS NULL
GROUP BY url;
CREATE OR REPLACE VIEW streamer_user_vw AS

View File

@ -40,22 +40,26 @@ export const updateStreamer = {
// Request-related queries
export const getRequests = {
name: "getRequests",
text: "SELECT * FROM get_requests() LIMIT $1"
text: "SELECT * FROM requests_vw \
JOIN states ON requests_vw.state = states.state \
WHERE active LIMIT $1"
}
export const getRequestsVoted = {
name: "getRequestsVoted",
text: "SELECT * FROM get_requests_voted($2) LIMIT $1"
text: "SELECT * FROM get_requests_voted($2) \
JOIN states ON get_requests_voted.state = states.state \
WHERE active LIMIT $1"
}
export const getAllRequests = {
name: "getAllRequests",
text: "SELECT * FROM get_requests_all() LIMIT $1"
text: "SELECT * FROM requests_vw() LIMIT $1"
}
export const getAllRequestsVoted = {
name: "getAllRequestsVoted",
text: "SELECT * FROM get_requests_all_voted($2) LIMIT $1"
text: "SELECT * FROM get_requests_voted($2) LIMIT $1"
}
export const checkRequestExists = {