Skip to content

Commit c44f36b

Browse files
authored
Merge pull request #6536 from sclubricants/RefactorBaseBuilderBatchNew
Refactor BaseBuilder *Batch() Methods
2 parents bd2d786 + f6a7aeb commit c44f36b

File tree

13 files changed

+503
-263
lines changed

13 files changed

+503
-263
lines changed

system/Database/BaseBuilder.php

Lines changed: 218 additions & 191 deletions
Large diffs are not rendered by default.

system/Database/MySQLi/Builder.php

Lines changed: 3 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -59,14 +59,8 @@ protected function _fromTables(): string
5959
/**
6060
* Generates a platform-specific batch update string from the supplied data
6161
*/
62-
protected function _updateBatch(string $table, array $values, string $index): string
62+
protected function _updateBatch(string $table, array $keys, array $values): string
6363
{
64-
// this is a work around until the rest of the platform is refactored
65-
if ($index !== '') {
66-
$this->QBOptions['constraints'] = [$index];
67-
}
68-
$keys = array_keys(current($values));
69-
7064
$sql = $this->QBOptions['sql'] ?? '';
7165

7266
// if this is the first iteration of batch then we need to build skeleton sql
@@ -89,7 +83,7 @@ protected function _updateBatch(string $table, array $values, string $index): st
8983

9084
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n";
9185

92-
$sql .= 'INNER JOIN (' . "\n%s";
86+
$sql .= 'INNER JOIN (' . "\n{:_table_:}";
9387

9488
$sql .= ') ' . $alias . "\n";
9589

@@ -135,6 +129,6 @@ protected function _updateBatch(string $table, array $values, string $index): st
135129
) . "\n";
136130
}
137131

138-
return sprintf($sql, $data);
132+
return str_replace('{:_table_:}', $data, $sql);
139133
}
140134
}

system/Database/OCI8/Builder.php

Lines changed: 26 additions & 25 deletions
Original file line numberDiff line numberDiff line change
@@ -68,29 +68,36 @@ class Builder extends BaseBuilder
6868
*/
6969
protected function _insertBatch(string $table, array $keys, array $values): string
7070
{
71-
$insertKeys = implode(', ', $keys);
72-
$hasPrimaryKey = in_array('PRIMARY', array_column($this->db->getIndexData($table), 'type'), true);
71+
$sql = $this->QBOptions['sql'] ?? '';
7372

74-
// ORA-00001 measures
75-
if ($hasPrimaryKey) {
76-
$sql = 'INSERT INTO ' . $table . ' (' . $insertKeys . ") \n SELECT * FROM (\n";
77-
$selectQueryValues = [];
73+
// if this is the first iteration of batch then we need to build skeleton sql
74+
if ($sql === '') {
75+
$insertKeys = implode(', ', $keys);
76+
$hasPrimaryKey = in_array('PRIMARY', array_column($this->db->getIndexData($table), 'type'), true);
7877

79-
foreach ($values as $value) {
80-
$selectValues = implode(',', array_map(static fn ($value, $key) => $value . ' as ' . $key, explode(',', substr(substr($value, 1), 0, -1)), $keys));
81-
$selectQueryValues[] = 'SELECT ' . $selectValues . ' FROM DUAL';
82-
}
78+
// ORA-00001 measures
79+
$sql = 'INSERT' . ($hasPrimaryKey ? '' : ' ALL') . ' INTO ' . $table . ' (' . $insertKeys . ")\n{:_table_:}";
8380

84-
return $sql . implode("\n UNION ALL \n", $selectQueryValues) . "\n)";
81+
$this->QBOptions['sql'] = $sql;
8582
}
8683

87-
$sql = "INSERT ALL\n";
88-
89-
foreach ($values as $value) {
90-
$sql .= ' INTO ' . $table . ' (' . $insertKeys . ') VALUES ' . $value . "\n";
84+
if (isset($this->QBOptions['fromQuery'])) {
85+
$data = $this->QBOptions['fromQuery'];
86+
} else {
87+
$data = implode(
88+
" FROM DUAL UNION ALL\n",
89+
array_map(
90+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
91+
static fn ($key, $index) => $index . ' ' . $key,
92+
$keys,
93+
$value
94+
)),
95+
$values
96+
)
97+
) . " FROM DUAL\n";
9198
}
9299

93-
return $sql . 'SELECT * FROM DUAL';
100+
return str_replace('{:_table_:}', $data, $sql);
94101
}
95102

96103
/**
@@ -232,14 +239,8 @@ protected function resetSelect()
232239
/**
233240
* Generates a platform-specific batch update string from the supplied data
234241
*/
235-
protected function _updateBatch(string $table, array $values, string $index): string
242+
protected function _updateBatch(string $table, array $keys, array $values): string
236243
{
237-
// this is a work around until the rest of the platform is refactored
238-
if ($index !== '') {
239-
$this->QBOptions['constraints'] = [$index];
240-
}
241-
$keys = array_keys(current($values));
242-
243244
$sql = $this->QBOptions['sql'] ?? '';
244245

245246
// if this is the first iteration of batch then we need to build skeleton sql
@@ -263,7 +264,7 @@ protected function _updateBatch(string $table, array $values, string $index): st
263264
// Oracle doesn't support ignore on updates so we will use MERGE
264265
$sql = 'MERGE INTO ' . $table . "\n";
265266

266-
$sql .= 'USING (' . "\n%s";
267+
$sql .= 'USING (' . "\n{:_table_:}";
267268

268269
$sql .= ') ' . $alias . "\n";
269270

@@ -311,6 +312,6 @@ protected function _updateBatch(string $table, array $values, string $index): st
311312
) . "\n";
312313
}
313314

314-
return sprintf($sql, $data);
315+
return str_replace('{:_table_:}', $data, $sql);
315316
}
316317
}

system/Database/Postgre/Builder.php

Lines changed: 18 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -196,7 +196,24 @@ protected function _insert(string $table, array $keys, array $unescapedKeys): st
196196
*/
197197
protected function _insertBatch(string $table, array $keys, array $values): string
198198
{
199-
return trim(sprintf('INSERT INTO %s (%s) VALUES %s %s', $table, implode(', ', $keys), implode(', ', $values), $this->compileIgnore('insert')));
199+
$sql = $this->QBOptions['sql'] ?? '';
200+
201+
// if this is the first iteration of batch then we need to build skeleton sql
202+
if ($sql === '') {
203+
$sql = 'INSERT INTO ' . $table . '(' . implode(', ', $keys) . ")\n{:_table_:}\n";
204+
205+
$sql .= $this->compileIgnore('insert');
206+
207+
$this->QBOptions['sql'] = $sql;
208+
}
209+
210+
if (isset($this->QBOptions['fromQuery'])) {
211+
$data = $this->QBOptions['fromQuery'];
212+
} else {
213+
$data = 'VALUES ' . implode(', ', $this->formatValues($values));
214+
}
215+
216+
return str_replace('{:_table_:}', $data, $sql);
200217
}
201218

202219
/**

system/Database/SQLSRV/Builder.php

Lines changed: 17 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -180,7 +180,23 @@ protected function _insert(string $table, array $keys, array $unescapedKeys): st
180180
*/
181181
protected function _insertBatch(string $table, array $keys, array $values): string
182182
{
183-
return 'INSERT ' . $this->compileIgnore('insert') . 'INTO ' . $this->getFullName($table) . ' (' . implode(', ', $keys) . ') VALUES ' . implode(', ', $values);
183+
$sql = $this->QBOptions['sql'] ?? '';
184+
185+
// if this is the first iteration of batch then we need to build skeleton sql
186+
if ($sql === '') {
187+
$sql = 'INSERT ' . $this->compileIgnore('insert') . 'INTO ' . $this->getFullName($table)
188+
. ' (' . implode(', ', $keys) . ")\n{:_table_:}";
189+
190+
$this->QBOptions['sql'] = $sql;
191+
}
192+
193+
if (isset($this->QBOptions['fromQuery'])) {
194+
$data = $this->QBOptions['fromQuery'];
195+
} else {
196+
$data = 'VALUES ' . implode(', ', $this->formatValues($values));
197+
}
198+
199+
return str_replace('{:_table_:}', $data, $sql);
184200
}
185201

186202
/**

system/Database/SQLite3/Builder.php

Lines changed: 13 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -12,6 +12,7 @@
1212
namespace CodeIgniter\Database\SQLite3;
1313

1414
use CodeIgniter\Database\BaseBuilder;
15+
use CodeIgniter\Database\Exceptions\DatabaseException;
1516

1617
/**
1718
* Builder for SQLite3
@@ -74,16 +75,26 @@ protected function _truncate(string $table): string
7475
/**
7576
* Generates a platform-specific batch update string from the supplied data
7677
*/
77-
protected function _updateBatch(string $table, array $values, string $index): string
78+
protected function _updateBatch(string $table, array $keys, array $values): string
7879
{
7980
if (version_compare($this->db->getVersion(), '3.33.0') >= 0) {
80-
return parent::_updateBatch($table, $values, $index);
81+
return parent::_updateBatch($table, $keys, $values);
8182
}
8283

84+
$constraints = $this->QBOptions['constraints'] ?? [];
85+
86+
if (count($constraints) > 1 || isset($this->QBOptions['fromQuery'])) {
87+
throw new DatabaseException('You are trying to use a feature which requires SQLite version 3.33 or higher.');
88+
}
89+
90+
$index = current($constraints);
91+
8392
$ids = [];
8493
$final = [];
8594

8695
foreach ($values as $val) {
96+
$val = array_combine($keys, $val);
97+
8798
$ids[] = $val[$index];
8899

89100
foreach (array_keys($val) as $field) {

tests/system/Database/Builder/InsertTest.php

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -265,7 +265,7 @@ public function testInsertBatchThrowsExceptionOnNoData()
265265
$builder = $this->db->table('jobs');
266266

267267
$this->expectException(DatabaseException::class);
268-
$this->expectExceptionMessage('You must use the "set" method to update an entry.');
268+
$this->expectExceptionMessage('insertBatch() has no data.');
269269
$builder->insertBatch();
270270
}
271271

@@ -274,7 +274,7 @@ public function testInsertBatchThrowsExceptionOnEmptyData()
274274
$builder = $this->db->table('jobs');
275275

276276
$this->expectException(DatabaseException::class);
277-
$this->expectExceptionMessage('insertBatch() called with no data');
277+
$this->expectExceptionMessage('insertBatch() has no data.');
278278
$builder->insertBatch([]);
279279
}
280280
}

tests/system/Database/Builder/UpdateTest.php

Lines changed: 25 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -234,11 +234,11 @@ public function testUpdateBatch()
234234
$expected = <<<'EOF'
235235
UPDATE "jobs"
236236
SET
237-
"name" = _u."name",
238-
"description" = _u."description"
237+
"description" = _u."description",
238+
"name" = _u."name"
239239
FROM (
240-
SELECT 2 "id", 'Comedian' "name", 'There''s something in your teeth' "description" UNION ALL
241-
SELECT 3 "id", 'Cab Driver' "name", 'I am yellow' "description"
240+
SELECT 'There''s something in your teeth' "description", 2 "id", 'Comedian' "name" UNION ALL
241+
SELECT 'I am yellow' "description", 3 "id", 'Cab Driver' "name"
242242
) _u
243243
WHERE "jobs"."id" = _u."id"
244244
EOF;
@@ -273,11 +273,11 @@ public function testSetUpdateBatchWithoutEscape()
273273
$expected = <<<'EOF'
274274
UPDATE "jobs"
275275
SET
276-
"name" = _u."name",
277-
"description" = _u."description"
276+
"description" = _u."description",
277+
"name" = _u."name"
278278
FROM (
279-
SELECT 2 "id", SUBSTRING(name, 1) "name", SUBSTRING(description, 3) "description" UNION ALL
280-
SELECT 3 "id", SUBSTRING(name, 2) "name", SUBSTRING(description, 4) "description"
279+
SELECT SUBSTRING(description, 3) "description", 2 "id", SUBSTRING(name, 1) "name" UNION ALL
280+
SELECT SUBSTRING(description, 4) "description", 3 "id", SUBSTRING(name, 2) "name"
281281
) _u
282282
WHERE "jobs"."id" = _u."id"
283283
EOF;
@@ -290,7 +290,7 @@ public function testUpdateBatchThrowsExceptionWithNoData()
290290
$builder = new BaseBuilder('jobs', $this->db);
291291

292292
$this->expectException(DatabaseException::class);
293-
$this->expectExceptionMessage('You must use the "set" method to update an entry.');
293+
$this->expectExceptionMessage('updateBatch() has no data.');
294294

295295
$builder->updateBatch(null, 'id');
296296
}
@@ -300,17 +300,30 @@ public function testUpdateBatchThrowsExceptionWithNoID()
300300
$builder = new BaseBuilder('jobs', $this->db);
301301

302302
$this->expectException(DatabaseException::class);
303-
$this->expectExceptionMessage('You must specify an index to match on for batch updates.');
303+
$this->expectExceptionMessage('You must specify a constraint to match on for batch updates.');
304+
305+
$set = [
306+
[
307+
'id' => 2,
308+
'name' => 'SUBSTRING(name, 1)',
309+
'description' => 'SUBSTRING(description, 3)',
310+
],
311+
[
312+
'id' => 3,
313+
'name' => 'SUBSTRING(name, 2)',
314+
'description' => 'SUBSTRING(description, 4)',
315+
],
316+
];
304317

305-
$builder->updateBatch([]);
318+
$builder->updateBatch($set, null);
306319
}
307320

308321
public function testUpdateBatchThrowsExceptionWithEmptySetArray()
309322
{
310323
$builder = new BaseBuilder('jobs', $this->db);
311324

312325
$this->expectException(DatabaseException::class);
313-
$this->expectExceptionMessage('updateBatch() called with no data');
326+
$this->expectExceptionMessage('updateBatch() has no data.');
314327

315328
$builder->updateBatch([], 'id');
316329
}

tests/system/Database/Live/UpdateTest.php

Lines changed: 86 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -12,6 +12,7 @@
1212
namespace CodeIgniter\Database\Live;
1313

1414
use CodeIgniter\Database\Exceptions\DatabaseException;
15+
use CodeIgniter\Database\RawSql;
1516
use CodeIgniter\Test\CIUnitTestCase;
1617
use CodeIgniter\Test\DatabaseTestTrait;
1718
use Config\Database;
@@ -238,4 +239,89 @@ public function testSetWithBoolean()
238239
'type_boolean' => true,
239240
]);
240241
}
242+
243+
public function testUpdateBatchTwoConstraints()
244+
{
245+
if (version_compare($this->db->getVersion(), '3.33.0') < 0) {
246+
$this->markTestSkipped('This SQLite version does not support this test.');
247+
}
248+
249+
$data = [
250+
[
251+
'id' => 1,
252+
'name' => 'Derek Jones Changes',
253+
'country' => 'US',
254+
],
255+
[
256+
'id' => 2,
257+
'name' => 'Ahmadinejad Does Not Change',
258+
'country' => 'Greece',
259+
],
260+
];
261+
262+
$this->db->table('user')->updateBatch($data, 'id, country');
263+
264+
$this->seeInDatabase('user', [
265+
'name' => 'Derek Jones Changes',
266+
'country' => 'US',
267+
]);
268+
$this->seeInDatabase('user', [
269+
'name' => 'Ahmadinejad',
270+
'country' => 'Iran',
271+
]);
272+
}
273+
274+
public function testUpdateBatchConstraintsRawSqlAndAlias()
275+
{
276+
if (version_compare($this->db->getVersion(), '3.33.0') < 0) {
277+
$this->markTestSkipped('This SQLite version does not support this test.');
278+
}
279+
280+
$data = [
281+
[
282+
'id' => 1,
283+
'name' => 'Derek Jones Changes',
284+
'country' => 'US',
285+
],
286+
[
287+
'id' => 2,
288+
'name' => 'Ahmadinejad Changes',
289+
'country' => 'Uruguay',
290+
],
291+
[
292+
'id' => 3,
293+
'name' => 'Richard A Causey Changes',
294+
'country' => 'US',
295+
],
296+
[
297+
'id' => 4,
298+
'name' => 'Chris Martin Does Not Change',
299+
'country' => 'Greece',
300+
],
301+
];
302+
303+
$this->db->table('user')->setData($data, true, 'd')->updateBatch(
304+
null,
305+
['id', new RawSql($this->db->protectIdentifiers('d')
306+
. '.' . $this->db->protectIdentifiers('country')
307+
. " LIKE 'U%'")]
308+
);
309+
310+
$this->seeInDatabase('user', [
311+
'name' => 'Derek Jones Changes',
312+
'country' => 'US',
313+
]);
314+
$this->seeInDatabase('user', [
315+
'name' => 'Ahmadinejad Changes',
316+
'country' => 'Uruguay',
317+
]);
318+
$this->seeInDatabase('user', [
319+
'name' => 'Richard A Causey Changes',
320+
'country' => 'US',
321+
]);
322+
$this->seeInDatabase('user', [
323+
'name' => 'Chris Martin',
324+
'country' => 'UK',
325+
]);
326+
}
241327
}

0 commit comments

Comments
 (0)