116 lines
4.0 KiB
PL/PgSQL
116 lines
4.0 KiB
PL/PgSQL
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 FUNCTION get_requests_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)
|
|
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)
|
|
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;
|