Skip to content

Commit 8ec1fa5

Browse files
committed
Redesign BatchUpdate() SQL
1 parent c82cbd6 commit 8ec1fa5

File tree

6 files changed

+151
-102
lines changed

6 files changed

+151
-102
lines changed

system/Database/BaseBuilder.php

Lines changed: 34 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -2202,30 +2202,46 @@ public function updateBatch(?array $set = null, ?string $index = null, int $batc
22022202
*/
22032203
protected function _updateBatch(string $table, array $values, string $index): string
22042204
{
2205-
$ids = [];
2206-
$final = [];
2205+
$keys = array_keys(current($values));
22072206

2208-
foreach ($values as $val) {
2209-
$ids[] = $val[$index];
2207+
// make array for future use with composite keys - `field`
2208+
// future: $this->QBOptions['constraints']
2209+
$constraints = [$index];
22102210

2211-
foreach (array_keys($val) as $field) {
2212-
if ($field !== $index) {
2213-
$final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field];
2214-
}
2215-
}
2216-
}
2211+
// future: $this->QBOptions['updateFields']
2212+
$updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true));
22172213

2218-
$cases = '';
2214+
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n";
22192215

2220-
foreach ($final as $k => $v) {
2221-
$cases .= $k . " = CASE \n"
2222-
. implode("\n", $v) . "\n"
2223-
. 'ELSE ' . $k . ' END, ';
2224-
}
2216+
$sql .= 'SET' . "\n";
22252217

2226-
$this->where($index . ' IN(' . implode(',', $ids) . ')', null, false);
2218+
$sql .= implode(
2219+
",\n",
2220+
array_map(static fn ($key) => $key . ' = u.' . $key, $updateFields)
2221+
) . "\n";
22272222

2228-
return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere');
2223+
$sql .= 'FROM (' . "\n";
2224+
2225+
$sql .= implode(
2226+
" UNION ALL\n",
2227+
array_map(
2228+
static function ($value) use ($keys) {
2229+
return 'SELECT ' . implode(', ', array_map(
2230+
static fn ($key, $index) => $index . ' ' . $key,
2231+
$keys,
2232+
$value
2233+
));
2234+
},
2235+
$values
2236+
)
2237+
) . "\n";
2238+
2239+
$sql .= ') u' . "\n";
2240+
2241+
return $sql .= 'WHERE ' . implode(
2242+
' AND ',
2243+
array_map(static fn ($key) => $table . '.' . $key . ' = u.' . $key, $constraints)
2244+
);
22292245
}
22302246

22312247
/**

system/Database/MySQLi/Builder.php

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -53,4 +53,51 @@ protected function _fromTables(): string
5353

5454
return implode(', ', $this->QBFrom);
5555
}
56+
57+
/**
58+
* Generates a platform-specific batch update string from the supplied data
59+
*/
60+
protected function _updateBatch(string $table, array $values, string $index): string
61+
{
62+
$keys = array_keys(current($values));
63+
64+
// make array for future use with composite keys - `field`
65+
// future: $this->QBOptions['constraints']
66+
$constraints = [$index];
67+
68+
// future: $this->QBOptions['updateFields']
69+
$updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true));
70+
71+
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . " AS t\n";
72+
73+
$sql .= 'INNER JOIN (' . "\n";
74+
75+
$sql .= implode(
76+
" UNION ALL\n",
77+
array_map(
78+
static function ($value) use ($keys) {
79+
return 'SELECT ' . implode(', ', array_map(
80+
static fn ($key, $index) => $index . ' ' . $key,
81+
$keys,
82+
$value
83+
));
84+
},
85+
$values
86+
)
87+
) . "\n";
88+
89+
$sql .= ') u' . "\n";
90+
91+
$sql .= 'ON ' . implode(
92+
' AND ',
93+
array_map(static fn ($key) => 't.' . $key . ' = u.' . $key, $constraints)
94+
) . "\n";
95+
96+
$sql .= 'SET' . "\n";
97+
98+
return $sql .= implode(
99+
",\n",
100+
array_map(static fn ($key) => 't.' . $key . ' = u.' . $key, $updateFields)
101+
);
102+
}
56103
}

system/Database/OCI8/Builder.php

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -227,4 +227,54 @@ protected function resetSelect()
227227
$this->limitUsed = false;
228228
parent::resetSelect();
229229
}
230+
231+
/**
232+
* Generates a platform-specific batch update string from the supplied data
233+
*/
234+
protected function _updateBatch(string $table, array $values, string $index): string
235+
{
236+
$keys = array_keys(current($values));
237+
238+
// make array for future use with composite keys - `field`
239+
// future: $this->QBOptions['constraints']
240+
$constraints = [$index];
241+
242+
// future: $this->QBOptions['updateFields']
243+
$updateFields = array_filter($keys, static fn ($index) => ! in_array($index, $constraints, true));
244+
245+
// Oracle doesn't support ignore on updates so we will use MERGE
246+
$sql = 'MERGE INTO ' . $table . " \"t\"\n";
247+
248+
$sql .= 'USING (' . "\n";
249+
250+
$sql .= implode(
251+
" UNION ALL\n",
252+
array_map(
253+
static function ($value) use ($keys) {
254+
return 'SELECT ' . implode(', ', array_map(
255+
static fn ($key, $index) => $index . ' ' . $key,
256+
$keys,
257+
$value
258+
)) . ' FROM DUAL';
259+
},
260+
$values
261+
)
262+
) . "\n";
263+
264+
$sql .= ') "u"' . "\n";
265+
266+
$sql .= 'ON (' . implode(
267+
' AND ',
268+
array_map(static fn ($key) => '"t".' . $key . ' = "u".' . $key, $constraints)
269+
) . ")\n";
270+
271+
$sql .= "WHEN MATCHED THEN UPDATE\n";
272+
273+
$sql .= 'SET' . "\n";
274+
275+
return $sql .= implode(
276+
",\n",
277+
array_map(static fn ($key) => '"t".' . $key . ' = "u".' . $key, $updateFields)
278+
);
279+
}
230280
}

system/Database/Postgre/Builder.php

Lines changed: 0 additions & 33 deletions
Original file line numberDiff line numberDiff line change
@@ -241,39 +241,6 @@ protected function _update(string $table, array $values): string
241241
return parent::_update($table, $values);
242242
}
243243

244-
/**
245-
* Generates a platform-specific batch update string from the supplied data
246-
*/
247-
protected function _updateBatch(string $table, array $values, string $index): string
248-
{
249-
$ids = [];
250-
$final = [];
251-
252-
foreach ($values as $val) {
253-
$ids[] = $val[$index];
254-
255-
foreach (array_keys($val) as $field) {
256-
if ($field !== $index) {
257-
$final[$field] ??= [];
258-
259-
$final[$field][] = "WHEN {$val[$index]} THEN {$val[$field]}";
260-
}
261-
}
262-
}
263-
264-
$cases = '';
265-
266-
foreach ($final as $k => $v) {
267-
$cases .= "{$k} = (CASE {$index}\n"
268-
. implode("\n", $v)
269-
. "\nELSE {$k} END), ";
270-
}
271-
272-
$this->where("{$index} IN(" . implode(',', $ids) . ')', null, false);
273-
274-
return "UPDATE {$table} SET " . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere');
275-
}
276-
277244
/**
278245
* Generates a platform-specific delete string from the supplied data
279246
*/

system/Database/SQLSRV/Builder.php

Lines changed: 0 additions & 33 deletions
Original file line numberDiff line numberDiff line change
@@ -205,39 +205,6 @@ protected function _update(string $table, array $values): string
205205
return $this->keyPermission ? $this->addIdentity($fullTableName, $statement) : $statement;
206206
}
207207

208-
/**
209-
* Update_Batch statement
210-
*
211-
* Generates a platform-specific batch update string from the supplied data
212-
*/
213-
protected function _updateBatch(string $table, array $values, string $index): string
214-
{
215-
$ids = [];
216-
$final = [];
217-
218-
foreach ($values as $val) {
219-
$ids[] = $val[$index];
220-
221-
foreach (array_keys($val) as $field) {
222-
if ($field !== $index) {
223-
$final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field];
224-
}
225-
}
226-
}
227-
228-
$cases = '';
229-
230-
foreach ($final as $k => $v) {
231-
$cases .= $k . " = CASE \n"
232-
. implode("\n", $v) . "\n"
233-
. 'ELSE ' . $k . ' END, ';
234-
}
235-
236-
$this->where($index . ' IN(' . implode(',', $ids) . ')', null, false);
237-
238-
return 'UPDATE ' . $this->compileIgnore('update') . ' ' . $this->getFullName($table) . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere');
239-
}
240-
241208
/**
242209
* Increments a numeric column by the specified value.
243210
*

tests/system/Database/Builder/UpdateTest.php

Lines changed: 20 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -233,15 +233,16 @@ public function testUpdateBatch()
233233

234234
$space = ' ';
235235

236-
$expected = <<<EOF
237-
UPDATE "jobs" SET "name" = CASE{$space}
238-
WHEN "id" = 2 THEN 'Comedian'
239-
WHEN "id" = 3 THEN 'Cab Driver'
240-
ELSE "name" END, "description" = CASE{$space}
241-
WHEN "id" = 2 THEN 'There''s something in your teeth'
242-
WHEN "id" = 3 THEN 'I am yellow'
243-
ELSE "description" END
244-
WHERE "id" IN(2,3)
236+
$expected = <<<'EOF'
237+
UPDATE "jobs"
238+
SET
239+
"name" = u."name",
240+
"description" = u."description"
241+
FROM (
242+
SELECT 2 "id", 'Comedian' "name", 'There''s something in your teeth' "description" UNION ALL
243+
SELECT 3 "id", 'Cab Driver' "name", 'I am yellow' "description"
244+
) u
245+
WHERE "jobs"."id" = u."id"
245246
EOF;
246247

247248
$this->assertSame($expected, $query->getQuery());
@@ -273,15 +274,16 @@ public function testSetUpdateBatchWithoutEscape()
273274

274275
$space = ' ';
275276

276-
$expected = <<<EOF
277-
UPDATE "jobs" SET "name" = CASE{$space}
278-
WHEN "id" = 2 THEN SUBSTRING(name, 1)
279-
WHEN "id" = 3 THEN SUBSTRING(name, 2)
280-
ELSE "name" END, "description" = CASE{$space}
281-
WHEN "id" = 2 THEN SUBSTRING(description, 3)
282-
WHEN "id" = 3 THEN SUBSTRING(description, 4)
283-
ELSE "description" END
284-
WHERE "id" IN(2,3)
277+
$expected = <<<'EOF'
278+
UPDATE "jobs"
279+
SET
280+
"name" = u."name",
281+
"description" = u."description"
282+
FROM (
283+
SELECT 2 "id", SUBSTRING(name, 1) "name", SUBSTRING(description, 3) "description" UNION ALL
284+
SELECT 3 "id", SUBSTRING(name, 2) "name", SUBSTRING(description, 4) "description"
285+
) u
286+
WHERE "jobs"."id" = u."id"
285287
EOF;
286288

287289
$this->assertSame($expected, $query->getQuery());

0 commit comments

Comments
 (0)