Statically count topic views.
This commit is contained in:
parent
06d0575831
commit
d1b9996764
2 changed files with 46 additions and 0 deletions
|
@ -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.
|
||||
|
|
43
database/2019_03_03_140632_add_static_topic_viewcount.php
Normal file
43
database/2019_03_03_140632_add_static_topic_viewcount.php
Normal file
|
@ -0,0 +1,43 @@
|
|||
<?php
|
||||
namespace Misuzu\DatabaseMigrations\AddStaticTopicViewcount;
|
||||
|
||||
use PDO;
|
||||
|
||||
function migrate_up(PDO $conn): void
|
||||
{
|
||||
$conn->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`;
|
||||
");
|
||||
}
|
Loading…
Reference in a new issue