summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
-rw-r--r--ChangeLog1
-rw-r--r--util/dump.sql5
-rw-r--r--util/updates/update_2.7.sql33
3 files changed, 37 insertions, 2 deletions
diff --git a/ChangeLog b/ChangeLog
index 1a4d2d20..a523e2ec 100644
--- a/ChangeLog
+++ b/ChangeLog
@@ -18,6 +18,7 @@ git - ?
- Remind the user to type English in several form fields
- Full reply button in Quick reply box + larger textarea in post form
- Removed visual-novels.net link from the interface
+ - Fixed bug with excluding AVG(vote) < 0 VNs from tag pages
2.6 - 2009-08-09
- New screen resolutions: 1024x600 and 1600x1200
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();
+