Merge pull request #15554 from strapi/fix/performance-issues-clean-order-mysql

Improve SQL queries when cleaning orders
This commit is contained in:
Pierre Noël 2023-01-25 15:53:15 +01:00 committed by GitHub
commit 85a9359756
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23

View File

@ -198,11 +198,12 @@ const cleanOrderColumns = async ({ id, attribute, db, inverseRelIds, transaction
return; return;
} }
switch (strapi.db.dialect.client) { // Handle databases that don't support window function ROW_NUMBER (here it's MySQL 5)
case 'mysql': if (!strapi.db.dialect.supportsWindowFunctions()) {
await cleanOrderColumnsForInnoDB({ id, attribute, db, inverseRelIds, transaction: trx }); await cleanOrderColumnsForOldDatabases({ id, attribute, db, inverseRelIds, transaction: trx });
break; return;
default: { }
const { joinTable } = attribute; const { joinTable } = attribute;
const { joinColumn, inverseJoinColumn, orderColumnName, inverseOrderColumnName } = joinTable; const { joinColumn, inverseJoinColumn, orderColumnName, inverseOrderColumnName } = joinTable;
const update = []; const update = [];
@ -230,6 +231,40 @@ const cleanOrderColumns = async ({ id, attribute, db, inverseRelIds, transaction
whereBinding.push(inverseJoinColumn.name, ...inverseRelIds); whereBinding.push(inverseJoinColumn.name, ...inverseRelIds);
} }
switch (strapi.db.dialect.client) {
case 'mysql':
// Here it's MariaDB and MySQL 8
await db
.getConnection()
.raw(
`UPDATE
?? as a,
(
SELECT ${select.join(', ')}
FROM ??
WHERE ${where.join(' OR ')}
) AS b
SET ${update.join(', ')}
WHERE b.id = a.id`,
[joinTable.name, ...selectBinding, joinTable.name, ...whereBinding, ...updateBinding]
)
.transacting(trx);
break;
/*
UPDATE
:joinTable: as a,
(
SELECT
id,
ROW_NUMBER() OVER ( PARTITION BY :joinColumn: ORDER BY :orderColumn:) AS src_order,
ROW_NUMBER() OVER ( PARTITION BY :inverseJoinColumn: ORDER BY :inverseOrderColumn:) AS inv_order
FROM :joinTable:
WHERE :joinColumn: = :id OR :inverseJoinColumn: IN (:inverseRelIds)
) AS b
SET :orderColumn: = b.src_order, :inverseOrderColumn: = b.inv_order
WHERE b.id = a.id;
*/
default: {
const joinTableName = addSchema(joinTable.name); const joinTableName = addSchema(joinTable.name);
// raw query as knex doesn't allow updating from a subquery // raw query as knex doesn't allow updating from a subquery
@ -249,7 +284,7 @@ const cleanOrderColumns = async ({ id, attribute, db, inverseRelIds, transaction
.transacting(trx); .transacting(trx);
/* /*
`UPDATE :joinTable: as a UPDATE :joinTable: as a
SET :orderColumn: = b.src_order, :inverseOrderColumn: = b.inv_order SET :orderColumn: = b.src_order, :inverseOrderColumn: = b.inv_order
FROM ( FROM (
SELECT SELECT
@ -259,7 +294,7 @@ const cleanOrderColumns = async ({ id, attribute, db, inverseRelIds, transaction
FROM :joinTable: FROM :joinTable:
WHERE :joinColumn: = :id OR :inverseJoinColumn: IN (:inverseRelIds) WHERE :joinColumn: = :id OR :inverseJoinColumn: IN (:inverseRelIds)
) AS b ) AS b
WHERE b.id = a.id`, WHERE b.id = a.id;
*/ */
} }
} }
@ -267,9 +302,9 @@ const cleanOrderColumns = async ({ id, attribute, db, inverseRelIds, transaction
/* /*
* Ensure that orders are following a 1, 2, 3 sequence, without gap. * Ensure that orders are following a 1, 2, 3 sequence, without gap.
* The use of a temporary table instead of a window function makes the query compatible with MySQL 5 and prevents some deadlocks to happen in innoDB databases * The use of a session variable instead of a window function makes the query compatible with MySQL 5
*/ */
const cleanOrderColumnsForInnoDB = async ({ const cleanOrderColumnsForOldDatabases = async ({
id, id,
attribute, attribute,
db, db,
@ -279,28 +314,25 @@ const cleanOrderColumnsForInnoDB = async ({
const { joinTable } = attribute; const { joinTable } = attribute;
const { joinColumn, inverseJoinColumn, orderColumnName, inverseOrderColumnName } = joinTable; const { joinColumn, inverseJoinColumn, orderColumnName, inverseOrderColumnName } = joinTable;
const now = new Date().valueOf(); const randomSuffix = `${new Date().valueOf()}_${randomBytes(16).toString('hex')}`;
const randomHex = randomBytes(16).toString('hex');
if (hasOrderColumn(attribute) && id) { if (hasOrderColumn(attribute) && id) {
const tempOrderTableName = `orderTable_${now}_${randomHex}`; // raw query as knex doesn't allow updating from a subquery
try { // https://github.com/knex/knex/issues/2504
const orderVar = `order_${randomSuffix}`;
await db.connection.raw(`SET @${orderVar} = 0;`).transacting(trx);
await db.connection await db.connection
.raw( .raw(
` `UPDATE :joinTableName: as a, (
CREATE TABLE :tempOrderTableName: SELECT id, (@${orderVar}:=@${orderVar} + 1) AS src_order
SELECT FROM :joinTableName:
id, WHERE :joinColumnName: = :id
( ORDER BY :orderColumnName:
SELECT count(*) ) AS b
FROM :joinTableName: b SET :orderColumnName: = b.src_order
WHERE a.:orderColumnName: >= b.:orderColumnName: AND a.:joinColumnName: = b.:joinColumnName: AND a.:joinColumnName: = :id WHERE a.id = b.id
) AS src_order AND a.:joinColumnName: = :id`,
FROM :joinTableName: a
WHERE a.:joinColumnName: = :id
`,
{ {
tempOrderTableName,
joinTableName: joinTable.name, joinTableName: joinTable.name,
orderColumnName, orderColumnName,
joinColumnName: joinColumn.name, joinColumnName: joinColumn.name,
@ -308,67 +340,42 @@ const cleanOrderColumnsForInnoDB = async ({
} }
) )
.transacting(trx); .transacting(trx);
// raw query as knex doesn't allow updating from a subquery
// https://github.com/knex/knex/issues/2504
await db.connection
.raw(
`UPDATE ?? as a, (SELECT * FROM ??) AS b
SET ?? = b.src_order
WHERE a.id = b.id`,
[joinTable.name, tempOrderTableName, orderColumnName]
)
.transacting(trx);
} finally {
await db.connection.raw(`DROP TABLE IF EXISTS ??`, [tempOrderTableName]).transacting(trx);
}
} }
if (hasInverseOrderColumn(attribute) && !isEmpty(inverseRelIds)) { if (hasInverseOrderColumn(attribute) && !isEmpty(inverseRelIds)) {
const tempInvOrderTableName = `invOrderTable_${now}_${randomHex}`; const orderVar = `order_${randomSuffix}`;
try { const columnVar = `col_${randomSuffix}`;
await db.connection.raw(`SET @${orderVar} = 0;`).transacting(trx);
await db.connection await db.connection
.raw( .raw(
` `UPDATE ?? as a, (
CREATE TABLE ??
SELECT SELECT
id, id,
( @${orderVar}:=CASE WHEN @${columnVar} = ?? THEN @${orderVar} + 1 ELSE 1 END AS inv_order,
SELECT count(*) @${columnVar}:=?? ??
FROM ?? b
WHERE a.?? >= b.?? AND a.?? = b.?? AND a.?? IN (${inverseRelIds
.map(() => '?')
.join(', ')})
) AS inv_order
FROM ?? a FROM ?? a
WHERE a.?? IN (${inverseRelIds.map(() => '?').join(', ')}) WHERE ?? IN(${inverseRelIds.map(() => '?').join(', ')})
`, ORDER BY ??, ??
) AS b
SET ?? = b.inv_order
WHERE a.id = b.id
AND a.?? IN(${inverseRelIds.map(() => '?').join(', ')})`,
[ [
tempInvOrderTableName,
joinTable.name, joinTable.name,
inverseOrderColumnName,
inverseOrderColumnName,
inverseJoinColumn.name, inverseJoinColumn.name,
inverseJoinColumn.name, inverseJoinColumn.name,
inverseJoinColumn.name, inverseJoinColumn.name,
joinTable.name,
inverseJoinColumn.name,
...inverseRelIds, ...inverseRelIds,
joinTable.name, inverseJoinColumn.name,
joinColumn.name,
inverseOrderColumnName,
inverseJoinColumn.name, inverseJoinColumn.name,
...inverseRelIds, ...inverseRelIds,
] ]
) )
.transacting(trx); .transacting(trx);
await db.connection
.raw(
`UPDATE ?? as a, (SELECT * FROM ??) AS b
SET ?? = b.inv_order
WHERE a.id = b.id`,
[joinTable.name, tempInvOrderTableName, inverseOrderColumnName]
)
.transacting(trx);
} finally {
await db.connection.raw(`DROP TABLE IF EXISTS ??`, [tempInvOrderTableName]).transacting(trx);
}
} }
}; };