Skip to content

Commit

Permalink
Redesign BatchUpdate() SQL
Browse files Browse the repository at this point in the history
  • Loading branch information
sclubricants committed Aug 19, 2022
1 parent f5ed714 commit 869064c
Show file tree
Hide file tree
Showing 7 changed files with 180 additions and 106 deletions.
50 changes: 32 additions & 18 deletions system/Database/BaseBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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)
);
}

/**
Expand Down
45 changes: 45 additions & 0 deletions system/Database/MySQLi/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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)
);
}
}
48 changes: 48 additions & 0 deletions system/Database/OCI8/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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)
);
}
}
33 changes: 0 additions & 33 deletions system/Database/Postgre/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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
*/
Expand Down
33 changes: 0 additions & 33 deletions system/Database/SQLSRV/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
35 changes: 35 additions & 0 deletions system/Database/SQLite3/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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');
}
}
42 changes: 20 additions & 22 deletions tests/system/Database/Builder/UpdateTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -231,17 +231,16 @@ public function testUpdateBatch()
$query = $this->db->getLastQuery();
$this->assertInstanceOf(MockQuery::class, $query);

$space = ' ';

$expected = <<<EOF
UPDATE "jobs" SET "name" = CASE{$space}
WHEN "id" = 2 THEN 'Comedian'
WHEN "id" = 3 THEN 'Cab Driver'
ELSE "name" END, "description" = CASE{$space}
WHEN "id" = 2 THEN 'There''s something in your teeth'
WHEN "id" = 3 THEN 'I am yellow'
ELSE "description" END
WHERE "id" IN(2,3)
$expected = <<<'EOF'
UPDATE "jobs"
SET
"name" = u."name",
"description" = u."description"
FROM (
SELECT 2 "id", 'Comedian' "name", 'There''s something in your teeth' "description" UNION ALL
SELECT 3 "id", 'Cab Driver' "name", 'I am yellow' "description"
) u
WHERE "jobs"."id" = u."id"
EOF;

$this->assertSame($expected, $query->getQuery());
Expand Down Expand Up @@ -271,17 +270,16 @@ public function testSetUpdateBatchWithoutEscape()
$query = $this->db->getLastQuery();
$this->assertInstanceOf(MockQuery::class, $query);

$space = ' ';

$expected = <<<EOF
UPDATE "jobs" SET "name" = CASE{$space}
WHEN "id" = 2 THEN SUBSTRING(name, 1)
WHEN "id" = 3 THEN SUBSTRING(name, 2)
ELSE "name" END, "description" = CASE{$space}
WHEN "id" = 2 THEN SUBSTRING(description, 3)
WHEN "id" = 3 THEN SUBSTRING(description, 4)
ELSE "description" END
WHERE "id" IN(2,3)
$expected = <<<'EOF'
UPDATE "jobs"
SET
"name" = u."name",
"description" = u."description"
FROM (
SELECT 2 "id", SUBSTRING(name, 1) "name", SUBSTRING(description, 3) "description" UNION ALL
SELECT 3 "id", SUBSTRING(name, 2) "name", SUBSTRING(description, 4) "description"
) u
WHERE "jobs"."id" = u."id"
EOF;

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

0 comments on commit 869064c

Please sign in to comment.