From 5658d5178debd0afa2aa10c0840a52eb53c239fd Mon Sep 17 00:00:00 2001 From: Yorhel Date: Fri, 18 Sep 2009 11:10:14 +0200 Subject: Fixed bug with excluding AVG(vote) < 0 VNs from tag pages This was *supposed* to be done in ce6d43aed955effe136f1ce3682828d2d43109cb --- util/dump.sql | 5 +++-- util/updates/update_2.7.sql | 33 +++++++++++++++++++++++++++++++++ 2 files changed, 36 insertions(+), 2 deletions(-) (limited to 'util') diff --git a/util/dump.sql b/util/dump.sql index c8dec7d6..aaa1a5e9 100644 --- a/util/dump.sql +++ b/util/dump.sql @@ -586,7 +586,7 @@ BEGIN -- grouped by (tag, vid, uid), so only one user votes on one parent tag per VN entry CREATE OR REPLACE TEMPORARY VIEW tags_vn_grouped AS SELECT tag, vid, uid, MAX(vote)::real AS vote, COALESCE(AVG(spoiler), 0)::real AS spoiler - FROM tags_vn_all WHERE vote > 0 GROUP BY tag, vid, uid; + FROM tags_vn_all GROUP BY tag, vid, uid; -- grouped by (tag, vid) and serialized into a table DROP INDEX IF EXISTS tags_vn_bayesian_tag; TRUNCATE tags_vn_bayesian; @@ -594,7 +594,8 @@ BEGIN SELECT tag, vid, COUNT(uid) AS users, AVG(vote)::real AS rating, (CASE WHEN AVG(spoiler) < 0.7 THEN 0 WHEN AVG(spoiler) > 1.3 THEN 2 ELSE 1 END)::smallint AS spoiler FROM tags_vn_grouped - GROUP BY tag, vid; + GROUP BY tag, vid + HAVING AVG(vote) > 0; CREATE INDEX tags_vn_bayesian_tag ON tags_vn_bayesian (tag); -- now perform the bayesian ranking calculation UPDATE tags_vn_bayesian tvs SET rating = diff --git a/util/updates/update_2.7.sql b/util/updates/update_2.7.sql index 0a851ca6..e9061106 100644 --- a/util/updates/update_2.7.sql +++ b/util/updates/update_2.7.sql @@ -73,3 +73,36 @@ SELECT tmp_edit_release(r.id) DROP FUNCTION tmp_edit_release(integer); + + +-- Really don't consider VNs with AVG(vote) < 0 on tag pages +CREATE OR REPLACE FUNCTION tag_vn_calc() RETURNS void AS $$ +BEGIN + -- all votes for all tags + CREATE OR REPLACE TEMPORARY VIEW tags_vn_all AS + SELECT * FROM tags_vn UNION SELECT * FROM tag_vn_childs(); + -- grouped by (tag, vid, uid), so only one user votes on one parent tag per VN entry + CREATE OR REPLACE TEMPORARY VIEW tags_vn_grouped AS + SELECT tag, vid, uid, MAX(vote)::real AS vote, COALESCE(AVG(spoiler), 0)::real AS spoiler + FROM tags_vn_all GROUP BY tag, vid, uid; + -- grouped by (tag, vid) and serialized into a table + DROP INDEX IF EXISTS tags_vn_bayesian_tag; + TRUNCATE tags_vn_bayesian; + INSERT INTO tags_vn_bayesian + SELECT tag, vid, COUNT(uid) AS users, AVG(vote)::real AS rating, + (CASE WHEN AVG(spoiler) < 0.7 THEN 0 WHEN AVG(spoiler) > 1.3 THEN 2 ELSE 1 END)::smallint AS spoiler + FROM tags_vn_grouped + GROUP BY tag, vid + HAVING AVG(vote) > 0; + CREATE INDEX tags_vn_bayesian_tag ON tags_vn_bayesian (tag); + -- now perform the bayesian ranking calculation + UPDATE tags_vn_bayesian tvs SET rating = + ((SELECT AVG(users)::real * AVG(rating)::real FROM tags_vn_bayesian WHERE tag = tvs.tag) + users*rating) + / ((SELECT AVG(users)::real FROM tags_vn_bayesian WHERE tag = tvs.tag) + users)::real; + -- and update the VN count in the tags table as well + UPDATE tags SET c_vns = (SELECT COUNT(*) FROM tags_vn_bayesian WHERE tag = id); + RETURN; +END; +$$ LANGUAGE plpgsql; +SELECT tag_vn_calc(); + -- cgit v1.2.3