Skip to content

Add BaseBuilder::deleteBatch() #6734

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 21 commits into from
Nov 21, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
10 changes: 9 additions & 1 deletion .github/workflows/test-phpcpd.yml
Original file line number Diff line number Diff line change
Expand Up @@ -43,4 +43,12 @@ jobs:
extensions: dom, mbstring

- name: Detect code duplication
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/
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
--exclude system/Database/Postgre/Builder.php
-- app/ public/ system/
96 changes: 95 additions & 1 deletion system/Database/BaseBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -1969,7 +1969,7 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri
}

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

/**
* Sets data and calls batchExecute to run queries
*
* @param array|object|null $set a dataset or select query
* @param array|RawSql|null $constraints
*
* @return false|int|string[] Number of rows affected or FALSE on failure, SQL array when testMode
*/
public function deleteBatch($set = null, $constraints = null, int $batchSize = 100)
{
$this->onConstraint($constraints);

if ($set !== null && $set !== []) {
$this->setData($set, true);
}

return $this->batchExecute('_deleteBatch', $batchSize);
}

/**
* Generates a platform-specific batch update string from the supplied data
*/
protected function _deleteBatch(string $table, array $keys, array $values): string
{
$sql = $this->QBOptions['sql'] ?? '';

// if this is the first iteration of batch then we need to build skeleton sql
if ($sql === '') {
$constraints = $this->QBOptions['constraints'] ?? [];

if ($constraints === []) {
if ($this->db->DBDebug) {
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}

$alias = $this->QBOptions['alias'] ?? '_u';

$sql = 'DELETE ' . $table . ' FROM ' . $table . "\n";

$sql .= "INNER JOIN (\n{:_table_:}";

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

$sql .= 'ON ' . implode(
' AND ',
array_map(
static fn ($key, $value) => (
$value instanceof RawSql ?
$value :
(
is_string($key) ?
$table . '.' . $key . ' = ' . $alias . '.' . $value :
$table . '.' . $value . ' = ' . $alias . '.' . $value
)
),
array_keys($constraints),
$constraints
)
);

// convert binds in where
foreach ($this->QBWhere as $key => $where) {
foreach ($this->binds as $field => $bind) {
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
}
}

$sql .= ' ' . $this->compileWhereHaving('QBWhere');

$this->QBOptions['sql'] = trim($sql);
}

if (isset($this->QBOptions['fromQuery'])) {
$data = $this->QBOptions['fromQuery'];
} else {
$data = implode(
" UNION ALL\n",
array_map(
static fn ($value) => 'SELECT ' . implode(', ', array_map(
static fn ($key, $index) => $index . ' ' . $key,
$keys,
$value
)),
$values
)
) . "\n";
}

return str_replace('{:_table_:}', $data, $sql);
}

/**
* Increments a numeric column by the specified value.
*
Expand Down
79 changes: 79 additions & 0 deletions system/Database/OCI8/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -434,4 +434,83 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri

return str_replace('{:_table_:}', $data, $sql);
}

/**
* Generates a platform-specific batch update string from the supplied data
*/
protected function _deleteBatch(string $table, array $keys, array $values): string
{
$sql = $this->QBOptions['sql'] ?? '';

// if this is the first iteration of batch then we need to build skeleton sql
if ($sql === '') {
$constraints = $this->QBOptions['constraints'] ?? [];

if ($constraints === []) {
if ($this->db->DBDebug) {
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}

$alias = $this->QBOptions['alias'] ?? '_u';

$sql = 'DELETE ' . $table . "\n";

$sql .= "WHERE EXISTS (SELECT * FROM (\n{:_table_:}";

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

$sql .= 'WHERE ' . implode(
' AND ',
array_map(
static fn ($key, $value) => (
$value instanceof RawSql ?
$value :
(
is_string($key) ?
$table . '.' . $key . ' = ' . $alias . '.' . $value :
$table . '.' . $value . ' = ' . $alias . '.' . $value
)
),
array_keys($constraints),
$constraints
)
);

// convert binds in where
foreach ($this->QBWhere as $key => $where) {
foreach ($this->binds as $field => $bind) {
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
}
}

$sql .= ' ' . str_replace(
'WHERE ',
'AND ',
$this->compileWhereHaving('QBWhere')
) . ')';

$this->QBOptions['sql'] = $sql;
}

if (isset($this->QBOptions['fromQuery'])) {
$data = $this->QBOptions['fromQuery'];
} else {
$data = implode(
" FROM DUAL UNION ALL\n",
array_map(
static fn ($value) => 'SELECT ' . implode(', ', array_map(
static fn ($key, $index) => $index . ' ' . $key,
$keys,
$value
)),
$values
)
) . " FROM DUAL\n";
}

return str_replace('{:_table_:}', $data, $sql);
}
}
79 changes: 79 additions & 0 deletions system/Database/Postgre/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -408,4 +408,83 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri

return str_replace('{:_table_:}', $data, $sql);
}

/**
* Generates a platform-specific batch update string from the supplied data
*/
protected function _deleteBatch(string $table, array $keys, array $values): string
{
$sql = $this->QBOptions['sql'] ?? '';

// if this is the first iteration of batch then we need to build skeleton sql
if ($sql === '') {
$constraints = $this->QBOptions['constraints'] ?? [];

if ($constraints === []) {
if ($this->db->DBDebug) {
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}

$alias = $this->QBOptions['alias'] ?? '_u';

$sql = 'DELETE FROM ' . $table . "\n";

$sql .= "USING (\n{:_table_:}";

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

$sql .= 'WHERE ' . implode(
' AND ',
array_map(
static fn ($key, $value) => (
$value instanceof RawSql ?
$value :
(
is_string($key) ?
$table . '.' . $key . ' = ' . $alias . '.' . $value :
$table . '.' . $value . ' = ' . $alias . '.' . $value
)
),
array_keys($constraints),
$constraints
)
);

// convert binds in where
foreach ($this->QBWhere as $key => $where) {
foreach ($this->binds as $field => $bind) {
$this->QBWhere[$key]['condition'] = str_replace(':' . $field . ':', $bind[0], $where['condition']);
}
}

$sql .= ' ' . str_replace(
'WHERE ',
'AND ',
$this->compileWhereHaving('QBWhere')
);

$this->QBOptions['sql'] = $sql;
}

if (isset($this->QBOptions['fromQuery'])) {
$data = $this->QBOptions['fromQuery'];
} else {
$data = implode(
" UNION ALL\n",
array_map(
static fn ($value) => 'SELECT ' . implode(', ', array_map(
static fn ($key, $index) => $index . ' ' . $key,
$keys,
$value
)),
$values
)
) . "\n";
}

return str_replace('{:_table_:}', $data, $sql);
}
}
64 changes: 64 additions & 0 deletions system/Database/SQLite3/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -211,4 +211,68 @@ protected function _upsertBatch(string $table, array $keys, array $values): stri

return str_replace('{:_table_:}', $data, $sql);
}

/**
* Generates a platform-specific batch update string from the supplied data
*/
protected function _deleteBatch(string $table, array $keys, array $values): string
{
$sql = $this->QBOptions['sql'] ?? '';

// if this is the first iteration of batch then we need to build skeleton sql
if ($sql === '') {
$constraints = $this->QBOptions['constraints'] ?? [];

if ($constraints === []) {
if ($this->db->DBDebug) {
throw new DatabaseException('You must specify a constraint to match on for batch deletes.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}

$sql = 'DELETE FROM ' . $table . "\n";

if (current($constraints) instanceof RawSql && $this->db->DBDebug) {
throw new DatabaseException('You cannot use RawSql for constraint in SQLite.');
// @codeCoverageIgnore
}

if (is_string(current(array_keys($constraints)))) {
$concat1 = implode(' || ', array_keys($constraints));
$concat2 = implode(' || ', array_values($constraints));
} else {
$concat1 = implode(' || ', $constraints);
$concat2 = $concat1;
}

$sql .= "WHERE {$concat1} IN (SELECT {$concat2} FROM (\n{:_table_:}))";

// where is not supported
if ($this->QBWhere !== [] && $this->db->DBDebug) {
throw new DatabaseException('You cannot use WHERE with SQLite.');
// @codeCoverageIgnore
}

$this->QBOptions['sql'] = $sql;
}

if (isset($this->QBOptions['fromQuery'])) {
$data = $this->QBOptions['fromQuery'];
} else {
$data = implode(
" UNION ALL\n",
array_map(
static fn ($value) => 'SELECT ' . implode(', ', array_map(
static fn ($key, $index) => $index . ' ' . $key,
$keys,
$value
)),
$values
)
) . "\n";
}

return str_replace('{:_table_:}', $data, $sql);
}
}
23 changes: 23 additions & 0 deletions tests/system/Database/Live/DeleteTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -67,4 +67,27 @@ public function testDeleteWithLimit()

$this->seeNumRecords(1, 'user', ['country' => 'US']);
}

public function testDeleteBatch()
{
$data = [
['userid' => 1, 'username' => 'Derek J', 'unused' => 'You can have fields you dont use'],
['userid' => 2, 'username' => 'Ahmadinejad', 'unused' => 'You can have fields you dont use'],
];

$builder = $this->db->table('user')
->setData($data, null, 'data')
->onConstraint(['id' => 'userid', 'name' => 'username']);

// SQLite does not support where for batch deletes
if ($this->db->DBDriver !== 'SQLite3') {
$builder->where('data.userid > 0');
}

$builder->deleteBatch();

$this->seeInDatabase('user', ['email' => '[email protected]', 'name' => 'Derek Jones']);

$this->dontSeeInDatabase('user', ['email' => '[email protected]', 'name' => 'Ahmadinejad']);
}
}
1 change: 1 addition & 0 deletions user_guide_src/source/changelogs/v4.3.0.rst
Original file line number Diff line number Diff line change
Expand Up @@ -193,6 +193,7 @@ Query Builder
- Improved the SQL structure for ``Builder::updateBatch()``. See :ref:`update-batch` for the details.
- Added ``when()`` and ``whenNot()`` methods to conditionally add clauses to the query. See :ref:`BaseBuilder::when() <db-builder-when>` for details.
- Added ``upsert()`` and ``upsertBatch()`` methods to QueryBuilder. See :ref:`upsert-data`.
- Added ``deleteBatch()`` methods to QueryBuilder. See :ref:`delete-batch`.

Forge
-----
Expand Down
Loading