Fixed orphan records and denormalization errors

This commit is contained in:
Marcin Kurczewski 2015-02-23 20:42:12 +01:00
parent e7ea60f293
commit 5f0706c0b4
3 changed files with 141 additions and 0 deletions

41
scripts/cron-stats.php Normal file
View file

@ -0,0 +1,41 @@
<?php
require_once(__DIR__
. DIRECTORY_SEPARATOR . '..'
. DIRECTORY_SEPARATOR . 'src'
. DIRECTORY_SEPARATOR . 'Bootstrap.php');
// Why this exists:
// 1. Some entities store a few basic stats in special columns for performance reasons. The benefit of such
// denormalization is vast.
// 2. The maintenance of the stats is implemented using triggers - when users tags a post, tag usage increases.
// 3. This mostly works.
// 4. Meanwhile, in order not to leave any orphans upon row deletions (e.g. have dangling postTags row after specific
// post removal), the database schema uses foreign keys with CASCADE option. This option recursively removes
// everything that would have missing references. This is good.
// 5. Here's the thing: row removals caused by CASCADE foreign key checks don't execute triggers. So if user removes a
// post, then although corresponding postTags entries will get deleted, ON postTags AFTER DELETE trigger will not
// execute, leaving the tags with invalid usage count.
//
// There are three possible solutions to this problem:
// 1. Implement all that logic in the appplication layer. I don't feel like doing this at all, it causes more havoc in
// the code and possibly adds even more holes to the whole denormalization maintenance process.
// 2. Convert CASCADE foreign checks to another set of triggers. This won't work for MySQL because of its limitations:
// >Can't update table 'comments' in stored function/trigger because it is already used by statement which invoked
// >this stored function/trigger
// Creating complex triggers will result very quickly in this error message (I tested it on postTags and posts, it
// did). I strongly believe the reason behind the error above is linked directly into the discussed MySQL's
// limitation.
// 3. Make a scripts like this. This is the easiest option out. The downside is that changes will be seen not
// immediately, but except for heavy tag maintenance, I don't see where such a delay in stat synchronization might
// really hurt.
use Szurubooru\DatabaseConnection;
$databaseConnection = Szurubooru\Injector::get(DatabaseConnection::class);
$pdo = $databaseConnection->getPDO();
$pdo->exec('UPDATE tags SET usages = (SELECT COUNT(1) FROM postTags WHERE tagId = tags.id)');
$pdo->exec('UPDATE posts SET tagCount = (SELECT COUNT(1) FROM postTags WHERE postId = posts.id)');
$pdo->exec('UPDATE posts SET score = (SELECT SUM(score) FROM scores WHERE postId = posts.id)');
$pdo->exec('UPDATE posts SET favCount = (SELECT COUNT(1) FROM favorites WHERE postId = posts.id)');
$pdo->exec('UPDATE posts SET lastFavTime = (SELECT MAX(time) FROM favorites WHERE postId = posts.id)');
$pdo->exec('UPDATE posts SET commentCount = (SELECT COUNT(1) FROM comments WHERE postId = posts.id)');
$pdo->exec('UPDATE posts SET lastCommentTime = (SELECT MAX(lastEditTime) FROM comments WHERE postId = posts.id)');

View file

@ -0,0 +1,99 @@
<?php
namespace Szurubooru\Upgrades;
use Szurubooru\DatabaseConnection;
class Upgrade35 implements IUpgrade
{
public function run(DatabaseConnection $databaseConnection)
{
$pdo = $databaseConnection->getPDO();
$this->removeOrphans($pdo);
$this->addPostForeignKeys($pdo);
$this->addTagForeignKeys($pdo);
$this->addUserForeignKeys($pdo);
}
private function addPostForeignKeys($pdo)
{
$pdo->exec('ALTER TABLE favorites MODIFY postId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE favorites ADD FOREIGN KEY (postId) REFERENCES posts(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE postNotes MODIFY postId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE postNotes ADD FOREIGN KEY (postId) REFERENCES posts(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE postRelations MODIFY post1id INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE postRelations MODIFY post2id INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE postRelations ADD FOREIGN KEY (post1id) REFERENCES posts(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE postRelations ADD FOREIGN KEY (post2id) REFERENCES posts(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE postTags MODIFY postId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE postTags ADD FOREIGN KEY (postId) REFERENCES posts(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE scores MODIFY postId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE scores ADD FOREIGN KEY (postId) REFERENCES posts(id) ON DELETE CASCADE');
}
private function addTagForeignKeys($pdo)
{
$pdo->exec('ALTER TABLE tagRelations MODIFY tag1id INT(11) UNSIGNED NOT NULL');
$pdo->exec('ALTER TABLE tagRelations MODIFY tag2id INT(11) UNSIGNED NOT NULL');
$pdo->exec('ALTER TABLE tagRelations ADD FOREIGN KEY (tag1id) REFERENCES tags(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE tagRelations ADD FOREIGN KEY (tag2id) REFERENCES tags(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE postTags MODIFY tagId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE postTags ADD FOREIGN KEY (tagId) REFERENCES tags(id) ON DELETE CASCADE');
}
private function addUserForeignKeys($pdo)
{
$pdo->exec('ALTER TABLE comments MODIFY userId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE comments ADD FOREIGN KEY (userId) REFERENCES users(id) ON DELETE SET NULL');
$pdo->exec('ALTER TABLE favorites MODIFY userId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE favorites ADD FOREIGN KEY (userId) REFERENCES users(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE posts MODIFY userId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE posts ADD FOREIGN KEY (userId) REFERENCES users(id) ON DELETE SET NULL');
$pdo->exec('ALTER TABLE scores MODIFY userId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE scores ADD FOREIGN KEY (userId) REFERENCES users(id) ON DELETE CASCADE');
$pdo->exec('ALTER TABLE snapshots MODIFY userId INT(11) UNSIGNED');
$pdo->exec('ALTER TABLE snapshots ADD FOREIGN KEY (userId) REFERENCES users(id) ON DELETE SET NULL');
}
private function removeOrphans($pdo)
{
$pdo->exec('
CREATE TEMPORARY TABLE tempTable
(SELECT postId FROM postTags WHERE
(SELECT COUNT(1) FROM posts WHERE posts.id = postId) = 0)');
$pdo->exec(
'DELETE FROM postTags WHERE EXISTS (SELECT 1 FROM tempTable WHERE tempTable.postId = postTags.postId)');
$pdo->exec('DROP TABLE tempTable');
$pdo->exec('
CREATE TEMPORARY TABLE tempTable
(SELECT postId FROM scores WHERE
(SELECT COUNT(1) FROM posts WHERE posts.id = postId) = 0)');
$pdo->exec(
'DELETE FROM scores WHERE EXISTS (SELECT 1 FROM tempTable WHERE tempTable.postId = scores.postId)');
$pdo->exec('DROP TABLE tempTable');
$pdo->exec('
DELETE FROM favorites
WHERE (SELECT COUNT(1) FROM posts WHERE posts.id = postId) = 0');
$pdo->exec('
DELETE FROM postNotes
WHERE (SELECT COUNT(1) FROM posts WHERE posts.id = postId) = 0');
$pdo->exec('
DELETE FROM postRelations
WHERE (SELECT COUNT(1) FROM posts WHERE (posts.id = post1id) OR (posts.id = post2id) = 0)');
$pdo->exec('
DELETE FROM tagRelations
WHERE (SELECT COUNT(1) FROM tags WHERE (tags.id = tag1id) OR (tags.id = tag2id) = 0)');
}
}

View file

@ -51,6 +51,7 @@ return [
$container->get(\Szurubooru\Upgrades\Upgrade32::class), $container->get(\Szurubooru\Upgrades\Upgrade32::class),
$container->get(\Szurubooru\Upgrades\Upgrade33::class), $container->get(\Szurubooru\Upgrades\Upgrade33::class),
$container->get(\Szurubooru\Upgrades\Upgrade34::class), $container->get(\Szurubooru\Upgrades\Upgrade34::class),
$container->get(\Szurubooru\Upgrades\Upgrade35::class),
]; ];
}), }),