Skip to content

Improve BaseBuilder::updateBatch() SQL #6373

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 13 commits into from
Sep 10, 2022
Merged
2 changes: 1 addition & 1 deletion .github/workflows/test-phpcpd.yml
Original file line number Diff line number Diff line change
Expand Up @@ -39,4 +39,4 @@ 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 -- 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 -- app/ public/ system/
132 changes: 117 additions & 15 deletions system/Database/BaseBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,22 @@ class BaseBuilder
*/
protected $QBIgnore = false;

/**
* QB Options data
* Holds additional options and data used to render SQL
* and is reset by resetWrite()
*
* @phpstan-var array{
* updateFields?: array,
* constraints?: array,
* fromQuery?: string,
* sql?: string,
* alias?: string
* }
* @var array
*/
protected $QBOptions;

/**
* A reference to the database connection.
*
Expand Down Expand Up @@ -1719,6 +1735,40 @@ public function getWhere($where = null, ?int $limit = null, ?int $offset = 0, bo
return $result;
}

/**
* Sets update fields for updateBatch
*
* @param string|string[] $set
* @param bool $addToDefault future use
* @param array|null $ignore ignores items in set
*
* @return $this
*/
protected function updateFields($set, bool $addToDefault = false, ?array $ignore = null)
{
if (! empty($set)) {
if (! is_array($set)) {
$set = explode(',', $set);
}

foreach ($set as $key => $value) {
if (! ($value instanceof RawSql)) {
$value = $this->db->protectIdentifiers($value);
}

if (is_numeric($key)) {
$key = $value;
}

if ($ignore === null || ! in_array($key, $ignore, true)) {
$this->QBOptions['updateFields'][$this->db->protectIdentifiers($key)] = $value;
}
}
}

return $this;
}

/**
* Compiles batch insert strings and runs the queries
*
Expand Down Expand Up @@ -2203,30 +2253,81 @@ public function updateBatch(?array $set = null, ?string $index = null, int $batc
*/
protected function _updateBatch(string $table, array $values, string $index): string
{
$ids = [];
$final = [];
// this is a work around until the rest of the platform is refactored
if ($index !== '') {
$this->QBOptions['constraints'] = [$index];
}
$keys = array_keys(current($values));

foreach ($values as $val) {
$ids[] = $val[$index];
$sql = $this->QBOptions['sql'] ?? '';

foreach (array_keys($val) as $field) {
if ($field !== $index) {
$final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field];
// 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 updates.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}
}

$cases = '';
$updateFields = $this->QBOptions['updateFields'] ??
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
[];

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

foreach ($final as $k => $v) {
$cases .= $k . " = CASE \n"
. implode("\n", $v) . "\n"
. 'ELSE ' . $k . ' END, ';
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n";

$sql .= 'SET' . "\n";

$sql .= implode(
",\n",
array_map(
static fn ($key, $value) => $key . ($value instanceof RawSql ?
' = ' . $value :
' = ' . $alias . '.' . $value),
array_keys($updateFields),
$updateFields
)
) . "\n";

$sql .= 'FROM (' . "\n%s";

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

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

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

$this->where($index . ' IN(' . implode(',', $ids) . ')', null, false);
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 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere');
return sprintf($sql, $data);
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

sprintf() was introduced here.

}

/**
Expand Down Expand Up @@ -2825,6 +2926,7 @@ protected function resetWrite()
'QBKeys' => [],
'QBLimit' => false,
'QBIgnore' => false,
'QBOptions' => [],
]);
}

Expand Down
84 changes: 84 additions & 0 deletions system/Database/MySQLi/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,8 @@
namespace CodeIgniter\Database\MySQLi;

use CodeIgniter\Database\BaseBuilder;
use CodeIgniter\Database\Exceptions\DatabaseException;
use CodeIgniter\Database\RawSql;

/**
* Builder for MySQLi
Expand Down Expand Up @@ -53,4 +55,86 @@ 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
{
// this is a work around until the rest of the platform is refactored
if ($index !== '') {
$this->QBOptions['constraints'] = [$index];
}
$keys = array_keys(current($values));

$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 updates.'); // @codeCoverageIgnore
}

return ''; // @codeCoverageIgnore
}

$updateFields = $this->QBOptions['updateFields'] ??
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
[];

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

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

$sql .= 'INNER JOIN (' . "\n%s";

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

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

$sql .= 'SET' . "\n";

$sql .= implode(
",\n",
array_map(
static fn ($key, $value) => $table . '.' . $key . ($value instanceof RawSql ?
' = ' . $value :
' = ' . $alias . '.' . $value),
array_keys($updateFields),
$updateFields
)
);

$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 sprintf($sql, $data);
}
}
86 changes: 86 additions & 0 deletions system/Database/OCI8/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@

use CodeIgniter\Database\BaseBuilder;
use CodeIgniter\Database\Exceptions\DatabaseException;
use CodeIgniter\Database\RawSql;

/**
* Builder for OCI8
Expand Down Expand Up @@ -227,4 +228,89 @@ 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
{
// this is a work around until the rest of the platform is refactored
if ($index !== '') {
$this->QBOptions['constraints'] = [$index];
}
$keys = array_keys(current($values));

$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 updates.');
}

return ''; // @codeCoverageIgnore
}

$updateFields = $this->QBOptions['updateFields'] ??
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
[];

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

// Oracle doesn't support ignore on updates so we will use MERGE
$sql = 'MERGE INTO ' . $table . "\n";

$sql .= 'USING (' . "\n%s";

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

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

$sql .= "WHEN MATCHED THEN UPDATE\n";

$sql .= 'SET' . "\n";

$sql .= implode(
",\n",
array_map(
static fn ($key, $value) => $table . '.' . $key . ($value instanceof RawSql ?
' = ' . $value :
' = ' . $alias . '.' . $value),
array_keys($updateFields),
$updateFields
)
);

$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
)) . ' FROM DUAL',
$values
)
) . "\n";
}

return sprintf($sql, $data);
}
}
Loading