From d1b99967643c54639811e5c2dce8407836af81b1 Mon Sep 17 00:00:00 2001 From: flashwave Date: Sun, 3 Mar 2019 16:11:34 +0100 Subject: [PATCH] Statically count topic views. --- README.md | 3 ++ ...3_03_140632_add_static_topic_viewcount.php | 43 +++++++++++++++++++ 2 files changed, 46 insertions(+) create mode 100644 database/2019_03_03_140632_add_static_topic_viewcount.php diff --git a/README.md b/README.md index c12ef039..af679100 100644 --- a/README.md +++ b/README.md @@ -11,3 +11,6 @@ - [node.js](https://nodejs.org/) (for the typescript and less compilers) - [Yarn](https://yarnpkg.com/) +## Additional Configuration + +Make sure to set the GLOBAL MySQL variable `log_bin_trust_function_creators` to `ON` so the migration script can create stored procedures. I can't automate this because said variable is not changeable at a session scope and only root can touch global variables. diff --git a/database/2019_03_03_140632_add_static_topic_viewcount.php b/database/2019_03_03_140632_add_static_topic_viewcount.php new file mode 100644 index 00000000..0a7ac103 --- /dev/null +++ b/database/2019_03_03_140632_add_static_topic_viewcount.php @@ -0,0 +1,43 @@ +exec(" + ALTER TABLE `msz_forum_topics` + ADD COLUMN `topic_count_views` INT UNSIGNED NOT NULL DEFAULT '0' AFTER `topic_title`; + "); + + $conn->exec(" + CREATE TRIGGER `msz_forum_topics_track_increase_views` + AFTER INSERT ON `msz_forum_topics_track` + FOR EACH ROW BEGIN + UPDATE `msz_forum_topics` + SET `topic_count_views` = `topic_count_views` + 1 + WHERE `topic_id` = NEW.topic_id; + END; + "); + + // Restore view counts + $conn->exec(" + UPDATE `msz_forum_topics` AS t + INNER JOIN ( + SELECT `topic_id`, COUNT(`user_id`) AS `count_views` + FROM `msz_forum_topics_track` + GROUP BY `topic_id` + ) AS tt + ON tt.`topic_id` = t.`topic_id` + SET t.`topic_count_views` = tt.`count_views` + "); +} + +function migrate_down(PDO $conn): void +{ + $conn->exec("DROP TRIGGER `msz_forum_topics_track_increase_views`"); + $conn->exec(" + ALTER TABLE `msz_forum_topics` + DROP COLUMN `topic_count_views`; + "); +}