learn-request-queue/db/90-views.sql

63 lines
2.2 KiB
MySQL
Raw Normal View History

2020-09-21 00:22:07 +00:00
CREATE OR REPLACE VIEW requests_vw AS
SELECT url,COALESCE(videoTitle,url) AS title,displayName AS requester,imageUrl,state,score,reqTimestamp FROM requests
JOIN requestMetadata USING (url)
2020-09-21 00:22:07 +00:00
JOIN scores USING (url)
JOIN users ON requests.requester = users.userid
ORDER BY score DESC, reqTimestamp ASC;
2020-08-08 04:32:06 +00:00
CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
RETURNS TABLE (
url varchar,
title varchar,
2020-08-08 04:32:06 +00:00
requester varchar,
imageUrl varchar,
2020-08-08 04:32:06 +00:00
state varchar,
score int,
reqTimestamp timestamptz,
voted bool
)
LANGUAGE SQL
AS $$
SELECT url,title,requester,imageUrl,state,score,reqTimestamp,
2020-08-08 04:32:06 +00:00
(CASE WHEN votes.userid IS NULL THEN FALSE ELSE TRUE END) AS voted
2020-09-21 00:22:07 +00:00
FROM requests_vw
LEFT JOIN votes ON (requests_vw.url = votes.requesturl AND votes.userid = votinguserid)
2020-08-08 04:32:06 +00:00
ORDER BY score DESC, reqTimestamp ASC;
$$;
/*
2020-09-21 00:22:07 +00:00
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
2020-08-08 04:32:06 +00:00
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_vw AS
2020-09-21 00:22:07 +00:00
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
2020-09-19 19:18:45 +00:00
FROM requests
2020-08-08 04:32:06 +00:00
LEFT JOIN votes ON votes.requesturl = requests.url
LEFT JOIN users on votes.userid = users.userid
2020-09-19 19:18:45 +00:00
LEFT JOIN bans ON users.userid = bans.userid
2020-09-21 00:22:07 +00:00
CROSS JOIN votepoints
WHERE bans.userid IS NULL
2020-08-08 04:32:06 +00:00
GROUP BY url;
2020-09-11 06:43:53 +00:00
CREATE OR REPLACE VIEW streamer_user_vw AS
SELECT users.userid as userid, users.displayname as displayname, users.imageurl as imageurl FROM streamer
LEFT JOIN users
ON streamer.userid = users.userid;