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

63 lines
2.3 KiB
PL/PgSQL

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)
JOIN scores USING (url)
JOIN users ON requests.requester = users.userid;
CREATE OR REPLACE FUNCTION get_requests_voted(votinguserid int)
RETURNS TABLE (
url varchar,
title varchar,
requester varchar,
imageUrl varchar,
state varchar,
score int,
reqTimestamp timestamptz,
voted bool
)
LANGUAGE SQL
AS $$
SELECT url,title,requester,imageUrl,state,score,reqTimestamp,
(CASE WHEN votes.userid IS NULL THEN FALSE ELSE TRUE END) AS voted
FROM requests_vw
LEFT JOIN votes ON (requests_vw.url = votes.requesturl AND votes.userid = votinguserid);
$$;
/*
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_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
AND votes.userid IS NOT 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 bans ON votes.userid = bans.userid
LEFT JOIN follows ON votes.userid = follows.userid
LEFT JOIN subscriptions ON votes.userid = subscriptions.userid
CROSS JOIN votepoints
WHERE bans.userid IS NULL
GROUP BY url;
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;