From 869064cc905a030d50db3c7e0002ca55c88ab163 Mon Sep 17 00:00:00 2001 From: sclubricants Date: Fri, 12 Aug 2022 15:46:38 -0700 Subject: [PATCH] Redesign BatchUpdate() SQL --- system/Database/BaseBuilder.php | 50 +++++++++++++------- system/Database/MySQLi/Builder.php | 45 ++++++++++++++++++ system/Database/OCI8/Builder.php | 48 +++++++++++++++++++ system/Database/Postgre/Builder.php | 33 ------------- system/Database/SQLSRV/Builder.php | 33 ------------- system/Database/SQLite3/Builder.php | 35 ++++++++++++++ tests/system/Database/Builder/UpdateTest.php | 42 ++++++++-------- 7 files changed, 180 insertions(+), 106 deletions(-) diff --git a/system/Database/BaseBuilder.php b/system/Database/BaseBuilder.php index 2310c1ba3509..ac9f712cf452 100644 --- a/system/Database/BaseBuilder.php +++ b/system/Database/BaseBuilder.php @@ -2202,30 +2202,44 @@ public function updateBatch(?array $set = null, ?string $index = null, int $batc */ protected function _updateBatch(string $table, array $values, string $index): string { - $ids = []; - $final = []; + $keys = array_keys(current($values)); - foreach ($values as $val) { - $ids[] = $val[$index]; + // make array for future use with composite keys - `field` + // future: $this->QBOptions['constraints'] + $constraints = [$index]; - foreach (array_keys($val) as $field) { - if ($field !== $index) { - $final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field]; - } - } - } + // future: $this->QBOptions['updateFields'] + $updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true)); - $cases = ''; + $sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n"; - foreach ($final as $k => $v) { - $cases .= $k . " = CASE \n" - . implode("\n", $v) . "\n" - . 'ELSE ' . $k . ' END, '; - } + $sql .= 'SET' . "\n"; - $this->where($index . ' IN(' . implode(',', $ids) . ')', null, false); + $sql .= implode( + ",\n", + array_map(static fn ($key) => $key . ' = u.' . $key, $updateFields) + ) . "\n"; - return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); + $sql .= 'FROM (' . "\n"; + + $sql .= implode( + " UNION ALL\n", + array_map( + static fn ($value) => 'SELECT ' . implode(', ', array_map( + static fn ($key, $index) => $index . ' ' . $key, + $keys, + $value + )), + $values + ) + ) . "\n"; + + $sql .= ') u' . "\n"; + + return $sql .= 'WHERE ' . implode( + ' AND ', + array_map(static fn ($key) => $table . '.' . $key . ' = u.' . $key, $constraints) + ); } /** diff --git a/system/Database/MySQLi/Builder.php b/system/Database/MySQLi/Builder.php index abeb83f8e4dc..8eb7cd37b05d 100644 --- a/system/Database/MySQLi/Builder.php +++ b/system/Database/MySQLi/Builder.php @@ -53,4 +53,49 @@ protected function _fromTables(): string return implode(', ', $this->QBFrom); } + + /** + * Generates a platform-specific batch update string from the supplied data + */ + protected function _updateBatch(string $table, array $values, string $index): string + { + $keys = array_keys(current($values)); + + // make array for future use with composite keys - `field` + // future: $this->QBOptions['constraints'] + $constraints = [$index]; + + // future: $this->QBOptions['updateFields'] + $updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true)); + + $sql = 'UPDATE ' . $this->compileIgnore('update') . $table . " AS t\n"; + + $sql .= 'INNER JOIN (' . "\n"; + + $sql .= implode( + " UNION ALL\n", + array_map( + static fn ($value) => 'SELECT ' . implode(', ', array_map( + static fn ($key, $index) => $index . ' ' . $key, + $keys, + $value + )), + $values + ) + ) . "\n"; + + $sql .= ') u' . "\n"; + + $sql .= 'ON ' . implode( + ' AND ', + array_map(static fn ($key) => 't.' . $key . ' = u.' . $key, $constraints) + ) . "\n"; + + $sql .= 'SET' . "\n"; + + return $sql .= implode( + ",\n", + array_map(static fn ($key) => 't.' . $key . ' = u.' . $key, $updateFields) + ); + } } diff --git a/system/Database/OCI8/Builder.php b/system/Database/OCI8/Builder.php index a954ec2337ad..4fbdb923283c 100644 --- a/system/Database/OCI8/Builder.php +++ b/system/Database/OCI8/Builder.php @@ -227,4 +227,52 @@ protected function resetSelect() $this->limitUsed = false; parent::resetSelect(); } + + /** + * Generates a platform-specific batch update string from the supplied data + */ + protected function _updateBatch(string $table, array $values, string $index): string + { + $keys = array_keys(current($values)); + + // make array for future use with composite keys - `field` + // future: $this->QBOptions['constraints'] + $constraints = [$index]; + + // future: $this->QBOptions['updateFields'] + $updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true)); + + // Oracle doesn't support ignore on updates so we will use MERGE + $sql = 'MERGE INTO ' . $table . " \"t\"\n"; + + $sql .= 'USING (' . "\n"; + + $sql .= implode( + " UNION ALL\n", + array_map( + static fn ($value) => 'SELECT ' . implode(', ', array_map( + static fn ($key, $index) => $index . ' ' . $key, + $keys, + $value + )) . ' FROM DUAL', + $values + ) + ) . "\n"; + + $sql .= ') "u"' . "\n"; + + $sql .= 'ON (' . implode( + ' AND ', + array_map(static fn ($key) => '"t".' . $key . ' = "u".' . $key, $constraints) + ) . ")\n"; + + $sql .= "WHEN MATCHED THEN UPDATE\n"; + + $sql .= 'SET' . "\n"; + + return $sql .= implode( + ",\n", + array_map(static fn ($key) => '"t".' . $key . ' = "u".' . $key, $updateFields) + ); + } } diff --git a/system/Database/Postgre/Builder.php b/system/Database/Postgre/Builder.php index 71c8a1f2b6c3..000d5923386c 100644 --- a/system/Database/Postgre/Builder.php +++ b/system/Database/Postgre/Builder.php @@ -241,39 +241,6 @@ protected function _update(string $table, array $values): string return parent::_update($table, $values); } - /** - * Generates a platform-specific batch update string from the supplied data - */ - protected function _updateBatch(string $table, array $values, string $index): string - { - $ids = []; - $final = []; - - foreach ($values as $val) { - $ids[] = $val[$index]; - - foreach (array_keys($val) as $field) { - if ($field !== $index) { - $final[$field] ??= []; - - $final[$field][] = "WHEN {$val[$index]} THEN {$val[$field]}"; - } - } - } - - $cases = ''; - - foreach ($final as $k => $v) { - $cases .= "{$k} = (CASE {$index}\n" - . implode("\n", $v) - . "\nELSE {$k} END), "; - } - - $this->where("{$index} IN(" . implode(',', $ids) . ')', null, false); - - return "UPDATE {$table} SET " . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); - } - /** * Generates a platform-specific delete string from the supplied data */ diff --git a/system/Database/SQLSRV/Builder.php b/system/Database/SQLSRV/Builder.php index c8b989f923ed..2354b71f7a93 100755 --- a/system/Database/SQLSRV/Builder.php +++ b/system/Database/SQLSRV/Builder.php @@ -205,39 +205,6 @@ protected function _update(string $table, array $values): string return $this->keyPermission ? $this->addIdentity($fullTableName, $statement) : $statement; } - /** - * Update_Batch statement - * - * Generates a platform-specific batch update string from the supplied data - */ - protected function _updateBatch(string $table, array $values, string $index): string - { - $ids = []; - $final = []; - - foreach ($values as $val) { - $ids[] = $val[$index]; - - foreach (array_keys($val) as $field) { - if ($field !== $index) { - $final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field]; - } - } - } - - $cases = ''; - - foreach ($final as $k => $v) { - $cases .= $k . " = CASE \n" - . implode("\n", $v) . "\n" - . 'ELSE ' . $k . ' END, '; - } - - $this->where($index . ' IN(' . implode(',', $ids) . ')', null, false); - - return 'UPDATE ' . $this->compileIgnore('update') . ' ' . $this->getFullName($table) . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); - } - /** * Increments a numeric column by the specified value. * diff --git a/system/Database/SQLite3/Builder.php b/system/Database/SQLite3/Builder.php index 588d2d0958e2..99ceadc99456 100644 --- a/system/Database/SQLite3/Builder.php +++ b/system/Database/SQLite3/Builder.php @@ -70,4 +70,39 @@ protected function _truncate(string $table): string { return 'DELETE FROM ' . $table; } + + /** + * Generates a platform-specific batch update string from the supplied data + */ + protected function _updateBatch(string $table, array $values, string $index): string + { + if (version_compare($this->db->getVersion(), '3.33.0') >= 0) { + return parent::_updateBatch($table, $values, $index); + } + + $ids = []; + $final = []; + + foreach ($values as $val) { + $ids[] = $val[$index]; + + foreach (array_keys($val) as $field) { + if ($field !== $index) { + $final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field]; + } + } + } + + $cases = ''; + + foreach ($final as $k => $v) { + $cases .= $k . " = CASE \n" + . implode("\n", $v) . "\n" + . 'ELSE ' . $k . ' END, '; + } + + $this->where($index . ' IN(' . implode(',', $ids) . ')', null, false); + + return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); + } } diff --git a/tests/system/Database/Builder/UpdateTest.php b/tests/system/Database/Builder/UpdateTest.php index 55eec68b8f2a..60104a7b4ff6 100644 --- a/tests/system/Database/Builder/UpdateTest.php +++ b/tests/system/Database/Builder/UpdateTest.php @@ -231,17 +231,16 @@ public function testUpdateBatch() $query = $this->db->getLastQuery(); $this->assertInstanceOf(MockQuery::class, $query); - $space = ' '; - - $expected = <<assertSame($expected, $query->getQuery()); @@ -271,17 +270,16 @@ public function testSetUpdateBatchWithoutEscape() $query = $this->db->getLastQuery(); $this->assertInstanceOf(MockQuery::class, $query); - $space = ' '; - - $expected = <<assertSame($expected, $query->getQuery());