From bbd4314cc10a564e959d5ef1edd937ef7524f46f Mon Sep 17 00:00:00 2001 From: Vitalii Yeromenko Date: Mon, 30 Nov 2020 15:42:36 +0000 Subject: [PATCH] BB-15683 Customer group may be duplicated on product visibility page if it was created with multiple customers and more than one consumer was running at the time - deleting the records that will become duplicated, before updating --- .../AbstractTableInformationQuery.php | 77 +++++++++ .../Query/AddScopeUniquenessQuery.php | 157 ++++++++++++++++-- 2 files changed, 219 insertions(+), 15 deletions(-) diff --git a/src/Oro/Bundle/MigrationBundle/Migration/AbstractTableInformationQuery.php b/src/Oro/Bundle/MigrationBundle/Migration/AbstractTableInformationQuery.php index 2d930000821..3da73417663 100644 --- a/src/Oro/Bundle/MigrationBundle/Migration/AbstractTableInformationQuery.php +++ b/src/Oro/Bundle/MigrationBundle/Migration/AbstractTableInformationQuery.php @@ -2,6 +2,7 @@ namespace Oro\Bundle\MigrationBundle\Migration; +use Doctrine\DBAL\Connection; use Doctrine\DBAL\Platforms\PostgreSqlPlatform; use Doctrine\DBAL\Types\Types; use Psr\Log\LoggerInterface; @@ -164,4 +165,80 @@ protected function getMySqlReferenceTableListQuery(): string rc.REFERENCED_TABLE_NAME = :table_name AND rc.CONSTRAINT_SCHEMA = :db_name'; } + + /** + * @param string $tableName + * @param array|string[] $ignoredFields + * @param LoggerInterface|null $logger + * @return array|string[] + * @throws \Doctrine\DBAL\DBALException + */ + protected function getUniqueColumnNames( + string $tableName, + array $ignoredFields = ['id'], + ?LoggerInterface $logger = null + ): array { + if ($this->connection->getDatabasePlatform() instanceof PostgreSqlPlatform) { + $sql = $this->getPgSqlUniqueColumnNamesQuery(); + $params = [ + 'namespace' => 'public', + 'table_name' => $tableName, + 'ignored_fields' => $ignoredFields, + ]; + $types = [ + 'namespace' => Types::STRING, + 'table_name' => Types::STRING, + 'ignored_fields' => Connection::PARAM_STR_ARRAY + ]; + } else { + $sql = $this->getMySqlUniqueColumnNamesQuery(); + $params = [ + 'db_name' => $this->connection->getDatabase(), + 'table_name' => $tableName, + 'ignored_fields' => $ignoredFields, + ]; + $types = [ + 'db_name' => Types::STRING, + 'table_name' => Types::STRING, + 'ignored_fields' => Connection::PARAM_STR_ARRAY + ]; + } + + if ($logger) { + $this->logQuery($logger, $sql, $params, $types); + } + + return $this->connection->fetchAll($sql, $params, $types); + } + + /** + * @return string + */ + protected function getPgSqlUniqueColumnNamesQuery(): string + { + return 'SELECT DISTINCT attr.attname as column_name + FROM pg_index pgi + JOIN pg_class idx on idx.oid = pgi.indexrelid + JOIN pg_namespace insp on insp.oid = idx.relnamespace + JOIN pg_class tbl on tbl.oid = pgi.indrelid + JOIN pg_namespace tnsp on tnsp.oid = tbl.relnamespace + JOIN pg_attribute attr on attr.attrelid = tbl.oid and attr.attnum = any(pgi.indkey) + WHERE pgi.indisunique + AND tnsp.nspname = :namespace + AND tbl.relname = :table_name + AND attr.attname NOT IN (:ignored_fields)'; + } + + /** + * @return string + */ + protected function getMySqlUniqueColumnNamesQuery(): string + { + return 'SELECT DISTINCT COLUMN_NAME as column_name + FROM information_schema.STATISTICS + WHERE TABLE_SCHEMA = :db_name + AND TABLE_NAME = :table_name + AND NON_UNIQUE = 0 + AND COLUMN_NAME not in (:ignored_fields)'; + } } diff --git a/src/Oro/Bundle/ScopeBundle/Migration/Query/AddScopeUniquenessQuery.php b/src/Oro/Bundle/ScopeBundle/Migration/Query/AddScopeUniquenessQuery.php index 12b37855004..ad97f391a52 100644 --- a/src/Oro/Bundle/ScopeBundle/Migration/Query/AddScopeUniquenessQuery.php +++ b/src/Oro/Bundle/ScopeBundle/Migration/Query/AddScopeUniquenessQuery.php @@ -62,23 +62,23 @@ protected function switchReferencesFromOldToNewScopes( LoggerInterface $logger, bool $dryRun ): void { - $types = ['toId' => Types::INTEGER, 'fromIds' => Connection::PARAM_INT_ARRAY]; - $references = $this->getReferenceTables('oro_scope', $logger); - foreach ($references as $reference) { - $qb = $this->connection->createQueryBuilder(); - $qb->update($reference['table_name']) - ->set($reference['column_name'], ':toId') - ->where($qb->expr()->in($reference['column_name'], ':fromIds')); - foreach ($newToOldScopeIdMap as $toId => $fromIds) { - $params = ['toId' => $toId, 'fromIds' => $fromIds]; - - $this->logQuery($logger, $qb->getSQL(), $params, $types); - if (!$dryRun) { - $qb->setParameters($params, $types)->execute(); - } - } + foreach ($references as $reference) { + $this->removeDuplicatesForUniqueRecords( + $reference['table_name'], + $reference['column_name'], + $newToOldScopeIdMap, + $logger, + $dryRun + ); + $this->migrateDuplicateScopes( + $reference['table_name'], + $reference['column_name'], + $newToOldScopeIdMap, + $logger, + $dryRun + ); } } @@ -136,4 +136,131 @@ protected function removeScopeDuplicates(array $newToOldScopeIdMap, LoggerInterf $this->connection->executeUpdate($deleteSql, $params, $types); } } + + /** + * @param string $tableName + * @param string $columnName + * @param array $newToOldScopeIdMap + * @param LoggerInterface $logger + * @param bool $dryRun + * @throws \Doctrine\DBAL\DBALException + */ + protected function removeDuplicatesForUniqueRecords( + string $tableName, + string $columnName, + array $newToOldScopeIdMap, + LoggerInterface $logger, + bool $dryRun + ): void { + $uniqueColumnNames = $this->getUniqueColumnNames($tableName, ['id', $columnName], $logger); + if ($uniqueColumnNames) { + foreach ($newToOldScopeIdMap as $toId => $fromIds) { + $types = [ + 'oldScopeId' => Connection::PARAM_INT_ARRAY, + 'newScopeId' => Types::INTEGER, + ]; + $params = ['oldScopeId' => $fromIds, 'newScopeId' => $toId]; + + $deleteSql = $this->getUpdateScopeQuery($tableName, $columnName, $uniqueColumnNames); + + $this->logQuery($logger, $deleteSql, $params, $types); + if (!$dryRun) { + $this->connection->executeQuery($deleteSql, $params, $types); + } + } + }; + } + + /** + * @param string $tableName + * @param string $columnName + * @param array $uniqueColumnNames + * @return string + */ + protected function getUpdateScopeQuery( + string $tableName, + string $columnName, + array $uniqueColumnNames + ) { + $deleteSql = sprintf( + 'delete from %s where %s in (:newScopeId, :oldScopeId)', + $tableName, + $columnName + ); + + foreach ($uniqueColumnNames as $uniqueColumnName) { + // double nested selects is a workaround for mysql not being able to delete from a table + // that is used in a sub-query + $deleteSql .= sprintf( + // Process only records that have duplicates and may lead to unique constraint violation + 'AND %2$s.%1$s in (SELECT t1.%1$s from ( + SELECT %2$s.%1$s FROM %2$s + WHERE %3$s in (:newScopeId, :oldScopeId) + GROUP BY %2$s.%1$s + HAVING COUNT(%2$s.%1$s) > 1 + ) as t1)' + // Skip one record among all duplicate scopes that will be used as a new and only one scope + record + . 'AND (%2$s.%1$s, %3$s) not in (SELECT t2.%1$s, scope_id from ( + SELECT %2$s.%1$s, MIN(%3$s) as scope_id FROM %2$s + WHERE %3$s in (:newScopeId, :oldScopeId) + GROUP BY %2$s.%1$s + HAVING COUNT(%2$s.%1$s) > 1 + ) as t2)', + $uniqueColumnName['column_name'], + $tableName, + $columnName + ); + } + + /** + * Example of the resulting query: for oro_cus_product_visibility table + * + * DELETE FROM oro_cus_product_visibility + * WHERE scope_id in (:newScopeId, :oldScopeId) + * AND product_id in (SELECT product_id from ( + * SELECT product_id FROM oro_cus_product_visibility + * WHERE scope_id in (:newScopeId, :oldScopeId) + * GROUP BY product_id + * HAVING COUNT(product_id) > 1 + * ) as t1) + * AND (product_id, scope_id) not in (SELECT product_id, scope_id from ( + * SELECT product_id, MIN(scope_id) as scope_id FROM oro_cus_product_visibility + * WHERE scope_id in (:newScopeId, :oldScopeId) + * GROUP BY product_id + * HAVING COUNT(product_id) > 1 + * ) as t2) + */ + + return $deleteSql; + } + + /** + * @param string $tableName + * @param string $columnName + * @param array $newToOldScopeIdMap + * @param LoggerInterface $logger + * @param bool $dryRun + */ + protected function migrateDuplicateScopes( + string $tableName, + string $columnName, + array $newToOldScopeIdMap, + LoggerInterface $logger, + bool $dryRun + ): void { + $types = ['toId' => Types::INTEGER, 'fromIds' => Connection::PARAM_INT_ARRAY]; + $qb = $this->connection->createQueryBuilder(); + $qb->update($tableName) + ->set($columnName, ':toId') + ->where($qb->expr()->in($columnName, ':fromIds')); + + foreach ($newToOldScopeIdMap as $toId => $fromIds) { + $params = ['toId' => $toId, 'fromIds' => $fromIds]; + + $this->logQuery($logger, $qb->getSQL(), $params, $types); + if (!$dryRun) { + $qb->setParameters($params, $types)->execute(); + } + } + } }