Skip to content

Commit 2477f08

Browse files
authored
Merge pull request #6734 from sclubricants/DeleteBatch
Add BaseBuilder::deleteBatch()
2 parents 672e154 + 9e611f2 commit 2477f08

File tree

9 files changed

+412
-2
lines changed

9 files changed

+412
-2
lines changed

.github/workflows/test-phpcpd.yml

Lines changed: 9 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -43,4 +43,12 @@ jobs:
4343
extensions: dom, mbstring
4444

4545
- name: Detect code duplication
46-
run: phpcpd --exclude system/Test --exclude system/ThirdParty --exclude system/Database/SQLSRV/Builder.php --exclude system/Database/SQLSRV/Forge.php --exclude system/Database/MySQLi/Builder.php --exclude system/Database/OCI8/Builder.php -- app/ public/ system/
46+
run: phpcpd
47+
--exclude system/Test
48+
--exclude system/ThirdParty
49+
--exclude system/Database/SQLSRV/Builder.php
50+
--exclude system/Database/SQLSRV/Forge.php
51+
--exclude system/Database/MySQLi/Builder.php
52+
--exclude system/Database/OCI8/Builder.php
53+
--exclude system/Database/Postgre/Builder.php
54+
-- app/ public/ system/

system/Database/BaseBuilder.php

Lines changed: 95 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1969,7 +1969,7 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri
19691969
}
19701970

19711971
/**
1972-
* Set table alias for dataset sudo table.
1972+
* Set table alias for dataset pseudo table.
19731973
*/
19741974
private function setAlias(string $alias): BaseBuilder
19751975
{
@@ -2653,6 +2653,100 @@ public function delete($where = '', ?int $limit = null, bool $resetData = true)
26532653
return $this->testMode ? $sql : $this->db->query($sql, $this->binds, false);
26542654
}
26552655

2656+
/**
2657+
* Sets data and calls batchExecute to run queries
2658+
*
2659+
* @param array|object|null $set a dataset or select query
2660+
* @param array|RawSql|null $constraints
2661+
*
2662+
* @return false|int|string[] Number of rows affected or FALSE on failure, SQL array when testMode
2663+
*/
2664+
public function deleteBatch($set = null, $constraints = null, int $batchSize = 100)
2665+
{
2666+
$this->onConstraint($constraints);
2667+
2668+
if ($set !== null && $set !== []) {
2669+
$this->setData($set, true);
2670+
}
2671+
2672+
return $this->batchExecute('_deleteBatch', $batchSize);
2673+
}
2674+
2675+
/**
2676+
* Generates a platform-specific batch update string from the supplied data
2677+
*/
2678+
protected function _deleteBatch(string $table, array $keys, array $values): string
2679+
{
2680+
$sql = $this->QBOptions['sql'] ?? '';
2681+
2682+
// if this is the first iteration of batch then we need to build skeleton sql
2683+
if ($sql === '') {
2684+
$constraints = $this->QBOptions['constraints'] ?? [];
2685+
2686+
if ($constraints === []) {
2687+
if ($this->db->DBDebug) {
2688+
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
2689+
}
2690+
2691+
return ''; // @codeCoverageIgnore
2692+
}
2693+
2694+
$alias = $this->QBOptions['alias'] ?? '_u';
2695+
2696+
$sql = 'DELETE ' . $table . ' FROM ' . $table . "\n";
2697+
2698+
$sql .= "INNER JOIN (\n{:_table_:}";
2699+
2700+
$sql .= ') ' . $alias . "\n";
2701+
2702+
$sql .= 'ON ' . implode(
2703+
' AND ',
2704+
array_map(
2705+
static fn ($key, $value) => (
2706+
$value instanceof RawSql ?
2707+
$value :
2708+
(
2709+
is_string($key) ?
2710+
$table . '.' . $key . ' = ' . $alias . '.' . $value :
2711+
$table . '.' . $value . ' = ' . $alias . '.' . $value
2712+
)
2713+
),
2714+
array_keys($constraints),
2715+
$constraints
2716+
)
2717+
);
2718+
2719+
// convert binds in where
2720+
foreach ($this->QBWhere as $key => $where) {
2721+
foreach ($this->binds as $field => $bind) {
2722+
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
2723+
}
2724+
}
2725+
2726+
$sql .= ' ' . $this->compileWhereHaving('QBWhere');
2727+
2728+
$this->QBOptions['sql'] = trim($sql);
2729+
}
2730+
2731+
if (isset($this->QBOptions['fromQuery'])) {
2732+
$data = $this->QBOptions['fromQuery'];
2733+
} else {
2734+
$data = implode(
2735+
" UNION ALL\n",
2736+
array_map(
2737+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
2738+
static fn ($key, $index) => $index . ' ' . $key,
2739+
$keys,
2740+
$value
2741+
)),
2742+
$values
2743+
)
2744+
) . "\n";
2745+
}
2746+
2747+
return str_replace('{:_table_:}', $data, $sql);
2748+
}
2749+
26562750
/**
26572751
* Increments a numeric column by the specified value.
26582752
*

system/Database/OCI8/Builder.php

Lines changed: 79 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -434,4 +434,83 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri
434434

435435
return str_replace('{:_table_:}', $data, $sql);
436436
}
437+
438+
/**
439+
* Generates a platform-specific batch update string from the supplied data
440+
*/
441+
protected function _deleteBatch(string $table, array $keys, array $values): string
442+
{
443+
$sql = $this->QBOptions['sql'] ?? '';
444+
445+
// if this is the first iteration of batch then we need to build skeleton sql
446+
if ($sql === '') {
447+
$constraints = $this->QBOptions['constraints'] ?? [];
448+
449+
if ($constraints === []) {
450+
if ($this->db->DBDebug) {
451+
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
452+
}
453+
454+
return ''; // @codeCoverageIgnore
455+
}
456+
457+
$alias = $this->QBOptions['alias'] ?? '_u';
458+
459+
$sql = 'DELETE ' . $table . "\n";
460+
461+
$sql .= "WHERE EXISTS (SELECT * FROM (\n{:_table_:}";
462+
463+
$sql .= ') ' . $alias . "\n";
464+
465+
$sql .= 'WHERE ' . implode(
466+
' AND ',
467+
array_map(
468+
static fn ($key, $value) => (
469+
$value instanceof RawSql ?
470+
$value :
471+
(
472+
is_string($key) ?
473+
$table . '.' . $key . ' = ' . $alias . '.' . $value :
474+
$table . '.' . $value . ' = ' . $alias . '.' . $value
475+
)
476+
),
477+
array_keys($constraints),
478+
$constraints
479+
)
480+
);
481+
482+
// convert binds in where
483+
foreach ($this->QBWhere as $key => $where) {
484+
foreach ($this->binds as $field => $bind) {
485+
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
486+
}
487+
}
488+
489+
$sql .= ' ' . str_replace(
490+
'WHERE ',
491+
'AND ',
492+
$this->compileWhereHaving('QBWhere')
493+
) . ')';
494+
495+
$this->QBOptions['sql'] = $sql;
496+
}
497+
498+
if (isset($this->QBOptions['fromQuery'])) {
499+
$data = $this->QBOptions['fromQuery'];
500+
} else {
501+
$data = implode(
502+
" FROM DUAL UNION ALL\n",
503+
array_map(
504+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
505+
static fn ($key, $index) => $index . ' ' . $key,
506+
$keys,
507+
$value
508+
)),
509+
$values
510+
)
511+
) . " FROM DUAL\n";
512+
}
513+
514+
return str_replace('{:_table_:}', $data, $sql);
515+
}
437516
}

system/Database/Postgre/Builder.php

Lines changed: 79 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -408,4 +408,83 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri
408408

409409
return str_replace('{:_table_:}', $data, $sql);
410410
}
411+
412+
/**
413+
* Generates a platform-specific batch update string from the supplied data
414+
*/
415+
protected function _deleteBatch(string $table, array $keys, array $values): string
416+
{
417+
$sql = $this->QBOptions['sql'] ?? '';
418+
419+
// if this is the first iteration of batch then we need to build skeleton sql
420+
if ($sql === '') {
421+
$constraints = $this->QBOptions['constraints'] ?? [];
422+
423+
if ($constraints === []) {
424+
if ($this->db->DBDebug) {
425+
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
426+
}
427+
428+
return ''; // @codeCoverageIgnore
429+
}
430+
431+
$alias = $this->QBOptions['alias'] ?? '_u';
432+
433+
$sql = 'DELETE FROM ' . $table . "\n";
434+
435+
$sql .= "USING (\n{:_table_:}";
436+
437+
$sql .= ') ' . $alias . "\n";
438+
439+
$sql .= 'WHERE ' . implode(
440+
' AND ',
441+
array_map(
442+
static fn ($key, $value) => (
443+
$value instanceof RawSql ?
444+
$value :
445+
(
446+
is_string($key) ?
447+
$table . '.' . $key . ' = ' . $alias . '.' . $value :
448+
$table . '.' . $value . ' = ' . $alias . '.' . $value
449+
)
450+
),
451+
array_keys($constraints),
452+
$constraints
453+
)
454+
);
455+
456+
// convert binds in where
457+
foreach ($this->QBWhere as $key => $where) {
458+
foreach ($this->binds as $field => $bind) {
459+
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
460+
}
461+
}
462+
463+
$sql .= ' ' . str_replace(
464+
'WHERE ',
465+
'AND ',
466+
$this->compileWhereHaving('QBWhere')
467+
);
468+
469+
$this->QBOptions['sql'] = $sql;
470+
}
471+
472+
if (isset($this->QBOptions['fromQuery'])) {
473+
$data = $this->QBOptions['fromQuery'];
474+
} else {
475+
$data = implode(
476+
" UNION ALL\n",
477+
array_map(
478+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
479+
static fn ($key, $index) => $index . ' ' . $key,
480+
$keys,
481+
$value
482+
)),
483+
$values
484+
)
485+
) . "\n";
486+
}
487+
488+
return str_replace('{:_table_:}', $data, $sql);
489+
}
411490
}

system/Database/SQLite3/Builder.php

Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -211,4 +211,68 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri
211211

212212
return str_replace('{:_table_:}', $data, $sql);
213213
}
214+
215+
/**
216+
* Generates a platform-specific batch update string from the supplied data
217+
*/
218+
protected function _deleteBatch(string $table, array $keys, array $values): string
219+
{
220+
$sql = $this->QBOptions['sql'] ?? '';
221+
222+
// if this is the first iteration of batch then we need to build skeleton sql
223+
if ($sql === '') {
224+
$constraints = $this->QBOptions['constraints'] ?? [];
225+
226+
if ($constraints === []) {
227+
if ($this->db->DBDebug) {
228+
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
229+
}
230+
231+
return ''; // @codeCoverageIgnore
232+
}
233+
234+
$sql = 'DELETE FROM ' . $table . "\n";
235+
236+
if (current($constraints) instanceof RawSql && $this->db->DBDebug) {
237+
throw new DatabaseException('You cannot use RawSql for constraint in SQLite.');
238+
// @codeCoverageIgnore
239+
}
240+
241+
if (is_string(current(array_keys($constraints)))) {
242+
$concat1 = implode(' || ', array_keys($constraints));
243+
$concat2 = implode(' || ', array_values($constraints));
244+
} else {
245+
$concat1 = implode(' || ', $constraints);
246+
$concat2 = $concat1;
247+
}
248+
249+
$sql .= "WHERE {$concat1} IN (SELECT {$concat2} FROM (\n{:_table_:}))";
250+
251+
// where is not supported
252+
if ($this->QBWhere !== [] && $this->db->DBDebug) {
253+
throw new DatabaseException('You cannot use WHERE with SQLite.');
254+
// @codeCoverageIgnore
255+
}
256+
257+
$this->QBOptions['sql'] = $sql;
258+
}
259+
260+
if (isset($this->QBOptions['fromQuery'])) {
261+
$data = $this->QBOptions['fromQuery'];
262+
} else {
263+
$data = implode(
264+
" UNION ALL\n",
265+
array_map(
266+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
267+
static fn ($key, $index) => $index . ' ' . $key,
268+
$keys,
269+
$value
270+
)),
271+
$values
272+
)
273+
) . "\n";
274+
}
275+
276+
return str_replace('{:_table_:}', $data, $sql);
277+
}
214278
}

tests/system/Database/Live/DeleteTest.php

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -67,4 +67,27 @@ public function testDeleteWithLimit()
6767

6868
$this->seeNumRecords(1, 'user', ['country' => 'US']);
6969
}
70+
71+
public function testDeleteBatch()
72+
{
73+
$data = [
74+
['userid' => 1, 'username' => 'Derek J', 'unused' => 'You can have fields you dont use'],
75+
['userid' => 2, 'username' => 'Ahmadinejad', 'unused' => 'You can have fields you dont use'],
76+
];
77+
78+
$builder = $this->db->table('user')
79+
->setData($data, null, 'data')
80+
->onConstraint(['id' => 'userid', 'name' => 'username']);
81+
82+
// SQLite does not support where for batch deletes
83+
if ($this->db->DBDriver !== 'SQLite3') {
84+
$builder->where('data.userid > 0');
85+
}
86+
87+
$builder->deleteBatch();
88+
89+
$this->seeInDatabase('user', ['email' => '[email protected]', 'name' => 'Derek Jones']);
90+
91+
$this->dontSeeInDatabase('user', ['email' => '[email protected]', 'name' => 'Ahmadinejad']);
92+
}
7093
}

user_guide_src/source/changelogs/v4.3.0.rst

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -193,6 +193,7 @@ Query Builder
193193
- Improved the SQL structure for ``Builder::updateBatch()``. See :ref:`update-batch` for the details.
194194
- Added ``when()`` and ``whenNot()`` methods to conditionally add clauses to the query. See :ref:`BaseBuilder::when() <db-builder-when>` for details.
195195
- Added ``upsert()`` and ``upsertBatch()`` methods to QueryBuilder. See :ref:`upsert-data`.
196+
- Added ``deleteBatch()`` methods to QueryBuilder. See :ref:`delete-batch`.
196197

197198
Forge
198199
-----

0 commit comments

Comments
 (0)