Optimize queries for orphaned scheduled task subscribers
[MAILPOET-6219]
This commit is contained in:
committed by
Aschepikov
parent
f3d6813d97
commit
53a1664133
@@ -40,9 +40,21 @@ class DataInconsistencyRepository {
|
|||||||
$stsTable = $this->entityManager->getClassMetadata(ScheduledTaskSubscriberEntity::class)->getTableName();
|
$stsTable = $this->entityManager->getClassMetadata(ScheduledTaskSubscriberEntity::class)->getTableName();
|
||||||
/** @var string $count */
|
/** @var string $count */
|
||||||
$count = $this->entityManager->getConnection()->executeQuery("
|
$count = $this->entityManager->getConnection()->executeQuery("
|
||||||
SELECT count(*) FROM $stsTable sts
|
SELECT COUNT(*)
|
||||||
LEFT JOIN $stTable st ON st.`id` = sts.`task_id`
|
FROM $stsTable sts
|
||||||
WHERE st.`id` IS NULL
|
WHERE sts.task_id IN (
|
||||||
|
-- SELECT ... FROM (subquery) forces the subquery to materialize first.
|
||||||
|
-- We're using this twice here to get the reduced data set before JOIN.
|
||||||
|
SELECT oprhaned_task_ids.task_id FROM
|
||||||
|
(
|
||||||
|
SELECT task_ids.task_id
|
||||||
|
FROM (
|
||||||
|
SELECT DISTINCT task_id FROM $stsTable
|
||||||
|
) AS task_ids
|
||||||
|
LEFT JOIN $stTable st ON st.id = task_ids.task_id
|
||||||
|
WHERE st.id IS NULL
|
||||||
|
) AS oprhaned_task_ids
|
||||||
|
);
|
||||||
")->fetchOne();
|
")->fetchOne();
|
||||||
return intval($count);
|
return intval($count);
|
||||||
}
|
}
|
||||||
@@ -146,17 +158,30 @@ class DataInconsistencyRepository {
|
|||||||
$stTable = $this->entityManager->getClassMetadata(ScheduledTaskEntity::class)->getTableName();
|
$stTable = $this->entityManager->getClassMetadata(ScheduledTaskEntity::class)->getTableName();
|
||||||
$stsTable = $this->entityManager->getClassMetadata(ScheduledTaskSubscriberEntity::class)->getTableName();
|
$stsTable = $this->entityManager->getClassMetadata(ScheduledTaskSubscriberEntity::class)->getTableName();
|
||||||
$deletedCount = 0;
|
$deletedCount = 0;
|
||||||
|
$missingTaskIds = $this->entityManager->getConnection()->executeQuery("
|
||||||
|
SELECT task_ids.task_id
|
||||||
|
-- SELECT ... FROM (subquery) forces the subquery to materialize first.
|
||||||
|
-- We're using this here to get the reduced data set before JOIN.
|
||||||
|
FROM (
|
||||||
|
SELECT DISTINCT task_id FROM $stsTable
|
||||||
|
) AS task_ids
|
||||||
|
LEFT JOIN $stTable st ON st.id = task_ids.task_id
|
||||||
|
WHERE st.id IS NULL;")->fetchFirstColumn();
|
||||||
|
|
||||||
|
if (!$missingTaskIds) {
|
||||||
|
return 0;
|
||||||
|
}
|
||||||
|
|
||||||
do {
|
do {
|
||||||
$deletedCount += (int)$this->entityManager->getConnection()->executeStatement(
|
$deletedCount += (int)$this->entityManager->getConnection()->executeStatement(
|
||||||
"DELETE sts_top FROM $stsTable sts_top
|
"DELETE sts_top FROM $stsTable sts_top
|
||||||
JOIN (
|
JOIN (
|
||||||
SELECT sts.`task_id`, sts.`subscriber_id` FROM $stsTable sts
|
SELECT sts.`task_id`, sts.`subscriber_id` FROM $stsTable sts
|
||||||
LEFT JOIN $stTable st ON st.`id` = sts.`task_id`
|
WHERE sts.`task_id` IN (:taskIds)
|
||||||
WHERE st.`id` IS NULL
|
|
||||||
LIMIT :limit
|
LIMIT :limit
|
||||||
) as to_delete ON sts_top.`task_id` = to_delete.`task_id` AND sts_top.`subscriber_id` = to_delete.`subscriber_id`",
|
) as to_delete ON sts_top.`task_id` = to_delete.`task_id` AND sts_top.`subscriber_id` = to_delete.`subscriber_id`",
|
||||||
['limit' => self::DELETE_ROWS_LIMIT],
|
['taskIds' => $missingTaskIds, 'limit' => self::DELETE_ROWS_LIMIT],
|
||||||
['limit' => ParameterType::INTEGER]
|
['taskIds' => ArrayParameterType::INTEGER, 'limit' => ParameterType::INTEGER]
|
||||||
);
|
);
|
||||||
} while ($this->getOrphanedScheduledTasksSubscribersCount() > 0);
|
} while ($this->getOrphanedScheduledTasksSubscribersCount() > 0);
|
||||||
return $deletedCount;
|
return $deletedCount;
|
||||||
|
Reference in New Issue
Block a user