Skip to content

Commit e249460

Browse files
authored
Merge pull request #6373 from sclubricants/BatchUpdateSQL
Improve `BaseBuilder::updateBatch()` SQL
2 parents bf55cde + c4cbaa7 commit e249460

File tree

11 files changed

+362
-119
lines changed

11 files changed

+362
-119
lines changed

.github/workflows/test-phpcpd.yml

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -39,4 +39,4 @@ jobs:
3939
extensions: dom, mbstring
4040

4141
- name: Detect code duplication
42-
run: phpcpd --exclude system/Test --exclude system/ThirdParty --exclude system/Database/SQLSRV/Builder.php --exclude system/Database/SQLSRV/Forge.php -- app/ public/ system/
42+
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/

system/Database/BaseBuilder.php

Lines changed: 117 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -153,6 +153,22 @@ class BaseBuilder
153153
*/
154154
protected $QBIgnore = false;
155155

156+
/**
157+
* QB Options data
158+
* Holds additional options and data used to render SQL
159+
* and is reset by resetWrite()
160+
*
161+
* @phpstan-var array{
162+
* updateFields?: array,
163+
* constraints?: array,
164+
* fromQuery?: string,
165+
* sql?: string,
166+
* alias?: string
167+
* }
168+
* @var array
169+
*/
170+
protected $QBOptions;
171+
156172
/**
157173
* A reference to the database connection.
158174
*
@@ -1719,6 +1735,40 @@ public function getWhere($where = null, ?int $limit = null, ?int $offset = 0, bo
17191735
return $result;
17201736
}
17211737

1738+
/**
1739+
* Sets update fields for updateBatch
1740+
*
1741+
* @param string|string[] $set
1742+
* @param bool $addToDefault future use
1743+
* @param array|null $ignore ignores items in set
1744+
*
1745+
* @return $this
1746+
*/
1747+
protected function updateFields($set, bool $addToDefault = false, ?array $ignore = null)
1748+
{
1749+
if (! empty($set)) {
1750+
if (! is_array($set)) {
1751+
$set = explode(',', $set);
1752+
}
1753+
1754+
foreach ($set as $key => $value) {
1755+
if (! ($value instanceof RawSql)) {
1756+
$value = $this->db->protectIdentifiers($value);
1757+
}
1758+
1759+
if (is_numeric($key)) {
1760+
$key = $value;
1761+
}
1762+
1763+
if ($ignore === null || ! in_array($key, $ignore, true)) {
1764+
$this->QBOptions['updateFields'][$this->db->protectIdentifiers($key)] = $value;
1765+
}
1766+
}
1767+
}
1768+
1769+
return $this;
1770+
}
1771+
17221772
/**
17231773
* Compiles batch insert strings and runs the queries
17241774
*
@@ -2203,30 +2253,81 @@ public function updateBatch(?array $set = null, ?string $index = null, int $batc
22032253
*/
22042254
protected function _updateBatch(string $table, array $values, string $index): string
22052255
{
2206-
$ids = [];
2207-
$final = [];
2256+
// this is a work around until the rest of the platform is refactored
2257+
if ($index !== '') {
2258+
$this->QBOptions['constraints'] = [$index];
2259+
}
2260+
$keys = array_keys(current($values));
22082261

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

2212-
foreach (array_keys($val) as $field) {
2213-
if ($field !== $index) {
2214-
$final[$field][] = 'WHEN ' . $index . ' = ' . $val[$index] . ' THEN ' . $val[$field];
2264+
// if this is the first iteration of batch then we need to build skeleton sql
2265+
if ($sql === '') {
2266+
$constraints = $this->QBOptions['constraints'] ?? [];
2267+
2268+
if ($constraints === []) {
2269+
if ($this->db->DBDebug) {
2270+
throw new DatabaseException('You must specify a constraint to match on for batch updates.'); // @codeCoverageIgnore
22152271
}
2272+
2273+
return ''; // @codeCoverageIgnore
22162274
}
2217-
}
22182275

2219-
$cases = '';
2276+
$updateFields = $this->QBOptions['updateFields'] ??
2277+
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
2278+
[];
2279+
2280+
$alias = $this->QBOptions['alias'] ?? '_u';
22202281

2221-
foreach ($final as $k => $v) {
2222-
$cases .= $k . " = CASE \n"
2223-
. implode("\n", $v) . "\n"
2224-
. 'ELSE ' . $k . ' END, ';
2282+
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n";
2283+
2284+
$sql .= 'SET' . "\n";
2285+
2286+
$sql .= implode(
2287+
",\n",
2288+
array_map(
2289+
static fn ($key, $value) => $key . ($value instanceof RawSql ?
2290+
' = ' . $value :
2291+
' = ' . $alias . '.' . $value),
2292+
array_keys($updateFields),
2293+
$updateFields
2294+
)
2295+
) . "\n";
2296+
2297+
$sql .= 'FROM (' . "\n%s";
2298+
2299+
$sql .= ') ' . $alias . "\n";
2300+
2301+
$sql .= 'WHERE ' . implode(
2302+
' AND ',
2303+
array_map(
2304+
static fn ($key) => ($key instanceof RawSql ?
2305+
$key :
2306+
$table . '.' . $key . ' = ' . $alias . '.' . $key),
2307+
$constraints
2308+
)
2309+
);
2310+
2311+
$this->QBOptions['sql'] = $sql;
22252312
}
22262313

2227-
$this->where($index . ' IN(' . implode(',', $ids) . ')', null, false);
2314+
if (isset($this->QBOptions['fromQuery'])) {
2315+
$data = $this->QBOptions['fromQuery'];
2316+
} else {
2317+
$data = implode(
2318+
" UNION ALL\n",
2319+
array_map(
2320+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
2321+
static fn ($key, $index) => $index . ' ' . $key,
2322+
$keys,
2323+
$value
2324+
)),
2325+
$values
2326+
)
2327+
) . "\n";
2328+
}
22282329

2229-
return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere');
2330+
return sprintf($sql, $data);
22302331
}
22312332

22322333
/**
@@ -2825,6 +2926,7 @@ protected function resetWrite()
28252926
'QBKeys' => [],
28262927
'QBLimit' => false,
28272928
'QBIgnore' => false,
2929+
'QBOptions' => [],
28282930
]);
28292931
}
28302932

system/Database/MySQLi/Builder.php

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

1414
use CodeIgniter\Database\BaseBuilder;
15+
use CodeIgniter\Database\Exceptions\DatabaseException;
16+
use CodeIgniter\Database\RawSql;
1517

1618
/**
1719
* Builder for MySQLi
@@ -53,4 +55,86 @@ protected function _fromTables(): string
5355

5456
return implode(', ', $this->QBFrom);
5557
}
58+
59+
/**
60+
* Generates a platform-specific batch update string from the supplied data
61+
*/
62+
protected function _updateBatch(string $table, array $values, string $index): string
63+
{
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+
70+
$sql = $this->QBOptions['sql'] ?? '';
71+
72+
// if this is the first iteration of batch then we need to build skeleton sql
73+
if ($sql === '') {
74+
$constraints = $this->QBOptions['constraints'] ?? [];
75+
76+
if ($constraints === []) {
77+
if ($this->db->DBDebug) {
78+
throw new DatabaseException('You must specify a constraint to match on for batch updates.'); // @codeCoverageIgnore
79+
}
80+
81+
return ''; // @codeCoverageIgnore
82+
}
83+
84+
$updateFields = $this->QBOptions['updateFields'] ??
85+
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
86+
[];
87+
88+
$alias = $this->QBOptions['alias'] ?? '`_u`';
89+
90+
$sql = 'UPDATE ' . $this->compileIgnore('update') . $table . "\n";
91+
92+
$sql .= 'INNER JOIN (' . "\n%s";
93+
94+
$sql .= ') ' . $alias . "\n";
95+
96+
$sql .= 'ON ' . implode(
97+
' AND ',
98+
array_map(
99+
static fn ($key) => ($key instanceof RawSql ?
100+
$key :
101+
$table . '.' . $key . ' = ' . $alias . '.' . $key),
102+
$constraints
103+
)
104+
) . "\n";
105+
106+
$sql .= 'SET' . "\n";
107+
108+
$sql .= implode(
109+
",\n",
110+
array_map(
111+
static fn ($key, $value) => $table . '.' . $key . ($value instanceof RawSql ?
112+
' = ' . $value :
113+
' = ' . $alias . '.' . $value),
114+
array_keys($updateFields),
115+
$updateFields
116+
)
117+
);
118+
119+
$this->QBOptions['sql'] = $sql;
120+
}
121+
122+
if (isset($this->QBOptions['fromQuery'])) {
123+
$data = $this->QBOptions['fromQuery'];
124+
} else {
125+
$data = implode(
126+
" UNION ALL\n",
127+
array_map(
128+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
129+
static fn ($key, $index) => $index . ' ' . $key,
130+
$keys,
131+
$value
132+
)),
133+
$values
134+
)
135+
) . "\n";
136+
}
137+
138+
return sprintf($sql, $data);
139+
}
56140
}

system/Database/OCI8/Builder.php

Lines changed: 86 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,7 @@
1313

1414
use CodeIgniter\Database\BaseBuilder;
1515
use CodeIgniter\Database\Exceptions\DatabaseException;
16+
use CodeIgniter\Database\RawSql;
1617

1718
/**
1819
* Builder for OCI8
@@ -227,4 +228,89 @@ protected function resetSelect()
227228
$this->limitUsed = false;
228229
parent::resetSelect();
229230
}
231+
232+
/**
233+
* Generates a platform-specific batch update string from the supplied data
234+
*/
235+
protected function _updateBatch(string $table, array $values, string $index): string
236+
{
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+
243+
$sql = $this->QBOptions['sql'] ?? '';
244+
245+
// if this is the first iteration of batch then we need to build skeleton sql
246+
if ($sql === '') {
247+
$constraints = $this->QBOptions['constraints'] ?? [];
248+
249+
if ($constraints === []) {
250+
if ($this->db->DBDebug) {
251+
throw new DatabaseException('You must specify a constraint to match on for batch updates.');
252+
}
253+
254+
return ''; // @codeCoverageIgnore
255+
}
256+
257+
$updateFields = $this->QBOptions['updateFields'] ??
258+
$this->updateFields($keys, false, $constraints)->QBOptions['updateFields'] ??
259+
[];
260+
261+
$alias = $this->QBOptions['alias'] ?? '"_u"';
262+
263+
// Oracle doesn't support ignore on updates so we will use MERGE
264+
$sql = 'MERGE INTO ' . $table . "\n";
265+
266+
$sql .= 'USING (' . "\n%s";
267+
268+
$sql .= ') ' . $alias . "\n";
269+
270+
$sql .= 'ON (' . implode(
271+
' AND ',
272+
array_map(
273+
static fn ($key) => ($key instanceof RawSql ?
274+
$key :
275+
$table . '.' . $key . ' = ' . $alias . '.' . $key),
276+
$constraints
277+
)
278+
) . ")\n";
279+
280+
$sql .= "WHEN MATCHED THEN UPDATE\n";
281+
282+
$sql .= 'SET' . "\n";
283+
284+
$sql .= implode(
285+
",\n",
286+
array_map(
287+
static fn ($key, $value) => $table . '.' . $key . ($value instanceof RawSql ?
288+
' = ' . $value :
289+
' = ' . $alias . '.' . $value),
290+
array_keys($updateFields),
291+
$updateFields
292+
)
293+
);
294+
295+
$this->QBOptions['sql'] = $sql;
296+
}
297+
298+
if (isset($this->QBOptions['fromQuery'])) {
299+
$data = $this->QBOptions['fromQuery'];
300+
} else {
301+
$data = implode(
302+
" UNION ALL\n",
303+
array_map(
304+
static fn ($value) => 'SELECT ' . implode(', ', array_map(
305+
static fn ($key, $index) => $index . ' ' . $key,
306+
$keys,
307+
$value
308+
)) . ' FROM DUAL',
309+
$values
310+
)
311+
) . "\n";
312+
}
313+
314+
return sprintf($sql, $data);
315+
}
230316
}

0 commit comments

Comments
 (0)