Skip to content

Commit 4668a27

Browse files
committed
Add Upsert/UpsertBatch to builder
1 parent 7808f18 commit 4668a27

File tree

7 files changed

+829
-1
lines changed

7 files changed

+829
-1
lines changed

system/Database/BaseBuilder.php

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

156+
/**
157+
* QB Options data
158+
*
159+
* @var array
160+
*/
161+
protected $QBOptions;
162+
156163
/**
157164
* A reference to the database connection.
158165
*
@@ -1719,6 +1726,238 @@ public function getWhere($where = null, ?int $limit = null, ?int $offset = 0, bo
17191726
return $result;
17201727
}
17211728

1729+
/**
1730+
* Compiles batch insert/upsert strings and runs the queries
1731+
*
1732+
* @throws DatabaseException
1733+
*
1734+
* @return false|int|string[] Number of rows inserted or FALSE on failure, SQL array when testMode
1735+
*/
1736+
public function batchExecute(string $renderMethod, ?array $set = null, ?bool $escape = null, int $batchSize = 100)
1737+
{
1738+
if ($set === null) {
1739+
if (empty($this->QBSet)) {
1740+
if ($this->db->DBDebug) {
1741+
throw new DatabaseException('You must use the "set" method to update an entry.');
1742+
}
1743+
1744+
return false; // @codeCoverageIgnore
1745+
}
1746+
} elseif (empty($set)) {
1747+
if ($this->db->DBDebug) {
1748+
throw new DatabaseException('insertBatch() called with no data');
1749+
}
1750+
1751+
return false; // @codeCoverageIgnore
1752+
}
1753+
1754+
$hasQBSet = $set === null;
1755+
1756+
$table = $this->QBFrom[0];
1757+
1758+
$affectedRows = 0;
1759+
$savedSQL = [];
1760+
1761+
if ($hasQBSet) {
1762+
$set = $this->QBSet;
1763+
}
1764+
1765+
for ($i = 0, $total = count($set); $i < $total; $i += $batchSize) {
1766+
if ($hasQBSet) {
1767+
$QBSet = array_slice($this->QBSet, $i, $batchSize);
1768+
} else {
1769+
$this->setBatch(array_slice($set, $i, $batchSize), '', $escape);
1770+
$QBSet = $this->QBSet;
1771+
}
1772+
$sql = $this->{$renderMethod}($this->db->protectIdentifiers($table, true, null, false), $this->QBKeys, $QBSet);
1773+
1774+
if ($this->testMode) {
1775+
$savedSQL[] = $sql;
1776+
} else {
1777+
$this->db->query($sql, null, false);
1778+
$affectedRows += $this->db->affectedRows();
1779+
}
1780+
1781+
if (! $hasQBSet) {
1782+
$this->resetRun([
1783+
'QBSet' => [],
1784+
'QBKeys' => [],
1785+
]);
1786+
}
1787+
}
1788+
1789+
$this->resetWrite();
1790+
1791+
return $this->testMode ? $savedSQL : $affectedRows;
1792+
}
1793+
1794+
/**
1795+
* Allows key/value pairs to be set for batch inserts/upserts
1796+
*
1797+
* @param mixed $key
1798+
*
1799+
* @return $this|null
1800+
*/
1801+
public function setBatch($key, string $value = '', ?bool $escape = null)
1802+
{
1803+
$key = $this->batchObjectToArray($key);
1804+
1805+
if (! is_array($key)) {
1806+
$key = [$key => $value];
1807+
}
1808+
1809+
$escape = is_bool($escape) ? $escape : $this->db->protectIdentifiers;
1810+
1811+
$keys = array_keys($this->objectToArray(current($key)));
1812+
sort($keys);
1813+
1814+
foreach ($key as $row) {
1815+
$row = $this->objectToArray($row);
1816+
if (array_diff($keys, array_keys($row)) !== [] || array_diff(array_keys($row), $keys) !== []) {
1817+
// batch function above returns an error on an empty array
1818+
$this->QBSet[] = [];
1819+
1820+
return null;
1821+
}
1822+
1823+
ksort($row); // puts $row in the same order as our keys
1824+
1825+
$clean = [];
1826+
1827+
foreach ($row as $rowValue) {
1828+
$clean[] = $escape ? $this->db->escape($rowValue) : $rowValue;
1829+
}
1830+
1831+
$row = $clean;
1832+
1833+
$this->QBSet[] = $row;
1834+
}
1835+
1836+
foreach ($keys as $k) {
1837+
$this->QBKeys[] = $this->db->protectIdentifiers($k, false);
1838+
}
1839+
1840+
return $this;
1841+
}
1842+
1843+
/**
1844+
* Compiles an upsert query and returns the sql
1845+
*
1846+
* @throws DatabaseException
1847+
*
1848+
* @return bool|string
1849+
*/
1850+
public function getCompiledUpsert(bool $reset = true)
1851+
{
1852+
$currentTestMode = $this->testMode;
1853+
1854+
$this->testMode = true;
1855+
1856+
$sql = implode(";\n", $this->upsert());
1857+
1858+
$this->testMode = $currentTestMode;
1859+
1860+
// this doesn't work with current implimentation - is cleared in upsert method
1861+
if ($reset === true) {
1862+
$this->resetWrite();
1863+
}
1864+
1865+
return $this->compileFinalQuery($sql);
1866+
}
1867+
1868+
/**
1869+
* Converts call to batchUpsert
1870+
*
1871+
* @param array|object|null $set
1872+
*
1873+
* @throws DatabaseException
1874+
*
1875+
* @return false|int|string[] Number of rows replaced or FALSE on failure, SQL array when testMode
1876+
*/
1877+
public function upsert($set = null, ?bool $escape = null)
1878+
{
1879+
if ($set === null) {
1880+
$set = empty($this->binds) ? null : [array_map(static fn ($columnName) => $columnName[0], $this->binds)];
1881+
1882+
$this->binds = [];
1883+
1884+
$this->resetRun([
1885+
'QBSet' => [],
1886+
'QBKeys' => [],
1887+
]);
1888+
} else {
1889+
$set = [$set];
1890+
}
1891+
1892+
return $this->batchExecute('_upsertBatch', $set, $escape, 1);
1893+
}
1894+
1895+
/**
1896+
* Compiles batch upsert strings and runs the queries
1897+
*
1898+
* @throws DatabaseException
1899+
*
1900+
* @return false|int|string[] Number of rows replaced or FALSE on failure, SQL array when testMode
1901+
*/
1902+
public function upsertBatch(?array $set = null, ?bool $escape = null, int $batchSize = 100)
1903+
{
1904+
return $this->batchExecute('_upsertBatch', $set, $escape, $batchSize);
1905+
}
1906+
1907+
/**
1908+
* Generates a platform-specific upsertBatch string from the supplied data
1909+
*/
1910+
protected function _upsertBatch(string $table, array $keys, array $values): string
1911+
{
1912+
$updateFields = $this->QBOptions['updateFields'] ?? $keys;
1913+
1914+
return 'INSERT INTO ' . $table . ' (' . implode(', ', $keys) . ') VALUES ' . implode(', ', $this->getValues($values)) . ' ON DUPLICATE KEY UPDATE ' . implode(', ', array_map(static fn ($columnName) => '`' . trim($columnName, '`') . '` = VALUES(`' . trim($columnName, '`') . '`)', $updateFields));
1915+
}
1916+
1917+
/**
1918+
* Sets constraints for upsert
1919+
*
1920+
* @param mixed $keys
1921+
*
1922+
* @return $this
1923+
*/
1924+
public function onConstraint($keys)
1925+
{
1926+
if (! is_array($keys)) {
1927+
$keys = explode(',', $keys);
1928+
}
1929+
1930+
$this->QBOptions['constraints'] = array_map(static fn ($key) => trim($key), $keys);
1931+
1932+
return $this;
1933+
}
1934+
1935+
/**
1936+
* Sets update fields for upsert
1937+
*
1938+
* @param mixed $keys
1939+
*
1940+
* @return $this
1941+
*/
1942+
public function updateFields($keys)
1943+
{
1944+
if (! is_array($keys)) {
1945+
$keys = explode(',', $keys);
1946+
}
1947+
1948+
$this->QBOptions['updateFields'] = array_map(static fn ($key) => trim($key), $keys);
1949+
1950+
return $this;
1951+
}
1952+
1953+
/**
1954+
* Converts value array of array to array of strings
1955+
*/
1956+
protected function getValues(array $values): array
1957+
{
1958+
return array_map(static fn ($index) => '(' . implode(',', $index) . ')', $values);
1959+
}
1960+
17221961
/**
17231962
* Compiles batch insert strings and runs the queries
17241963
*
@@ -2828,6 +3067,7 @@ protected function resetWrite()
28283067
'QBKeys' => [],
28293068
'QBLimit' => false,
28303069
'QBIgnore' => false,
3070+
'QBOptions' => [],
28313071
]);
28323072
}
28333073

system/Database/OCI8/Builder.php

Lines changed: 61 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -92,6 +92,67 @@ protected function _insertBatch(string $table, array $keys, array $values): stri
9292
return $sql . 'SELECT * FROM DUAL';
9393
}
9494

95+
/**
96+
* Generates a platform-specific upsertBatch string from the supplied data
97+
*/
98+
protected function _upsertBatch(string $table, array $keys, array $values): string
99+
{
100+
$fieldNames = array_map(static fn ($columnName) => trim($columnName, '"'), $keys);
101+
102+
$constraints = $this->QBOptions['constraints'] ?? [];
103+
104+
$updateFields = $this->QBOptions['updateFields'] ?? [];
105+
106+
if (empty($constraints)) {
107+
$uniqueIndexes = array_filter($this->db->getIndexData($table), static function ($index) use ($fieldNames) {
108+
$hasAllFields = count(array_intersect($index->fields, $fieldNames)) === count($index->fields);
109+
110+
return ($index->type === 'PRIMARY' || $index->type === 'UNIQUE') && $hasAllFields;
111+
});
112+
113+
// only take first index
114+
foreach ($uniqueIndexes as $index) {
115+
$constraints = $index->fields;
116+
break;
117+
}
118+
119+
$this->QBOptions['constraints'] = $constraints;
120+
}
121+
122+
if (empty($updateFields)) {
123+
$updateFields = array_filter($fieldNames, static fn ($columnName) => ! (in_array($columnName, $constraints, true)));
124+
125+
$this->QBOptions['updateFields'] = $updateFields;
126+
}
127+
128+
if (empty($constraints)) {
129+
throw new DatabaseException('No constraint found for upsert.');
130+
}
131+
132+
$sql = 'MERGE INTO ' . $table . "\nUSING (\n";
133+
134+
foreach ($values as $value) {
135+
$sql .= 'SELECT ' . implode(', ', array_map(static fn ($columnName, $value) => $value . ' ' . $columnName, $keys, $value)) . " FROM DUAL UNION ALL\n";
136+
}
137+
138+
$sql = substr($sql, 0, -11) . "\n";
139+
140+
$sql .= ') "_upsert"' . "\nON ( ";
141+
142+
$onList = [];
143+
$onList[] = '1 != 1';
144+
145+
$onList[] = '(' . implode(' AND ', array_map(static fn ($columnName) => $table . '."' . $columnName . '" = "_upsert"."' . $columnName . '"', $constraints)) . ')';
146+
147+
$sql .= implode(' OR ', $onList) . ")\nWHEN MATCHED THEN UPDATE SET ";
148+
149+
$sql .= implode(', ', array_map(static fn ($columnName) => '"' . $columnName . '"' . ' = "_upsert"."' . $columnName . '"', $updateFields));
150+
151+
$sql .= "\nWHEN NOT MATCHED THEN INSERT (" . implode(', ', $keys) . ")\nVALUES ";
152+
153+
return $sql . (' (' . implode(', ', array_map(static fn ($columnName) => '"_upsert".' . $columnName, $keys)) . ')');
154+
}
155+
95156
/**
96157
* Generates a platform-specific replace string from the supplied data
97158
*/

system/Database/OCI8/Forge.php

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -163,7 +163,7 @@ protected function _attributeAutoIncrement(array &$attributes, array &$field)
163163
&& stripos($field['type'], 'NUMBER') !== false
164164
&& version_compare($this->db->getVersion(), '12.1', '>=')
165165
) {
166-
$field['auto_increment'] = ' GENERATED BY DEFAULT AS IDENTITY';
166+
$field['auto_increment'] = ' GENERATED BY DEFAULT ON NULL AS IDENTITY';
167167
}
168168
}
169169

system/Database/Postgre/Builder.php

Lines changed: 53 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -199,6 +199,59 @@ protected function _insertBatch(string $table, array $keys, array $values): stri
199199
return trim(sprintf('INSERT INTO %s (%s) VALUES %s %s', $table, implode(', ', $keys), implode(', ', $values), $this->compileIgnore('insert')));
200200
}
201201

202+
/**
203+
* Generates a platform-specific upsertBatch string from the supplied data
204+
*/
205+
protected function _upsertBatch(string $table, array $keys, array $values): string
206+
{
207+
$fieldNames = array_map(static fn ($columnName) => trim($columnName, '"'), $keys);
208+
209+
$constraints = $this->QBOptions['constraints'] ?? [];
210+
211+
$updateFields = $this->QBOptions['updateFields'] ?? $fieldNames;
212+
213+
if (empty($constraints)) {
214+
$allIndexes = array_filter($this->db->getIndexData($table), static function ($index) use ($fieldNames) {
215+
$hasAllFields = count(array_intersect($index->fields, $fieldNames)) === count($index->fields);
216+
217+
return ($index->type === 'UNIQUE' || $index->type === 'PRIMARY') && $hasAllFields;
218+
});
219+
220+
foreach (array_map(static fn ($index) => $index->fields, $allIndexes) as $index) {
221+
foreach ($index as $constraint) {
222+
$constraints[] = $constraint;
223+
}
224+
// only one index can be used?
225+
break;
226+
}
227+
228+
$this->QBOptions['constraints'] = $constraints;
229+
}
230+
231+
// in value set - replace null with DEFAULT where constraint is presumed not null
232+
// autoincrement identity field must use DEFAULT and not NULL
233+
foreach ($constraints as $constraint) {
234+
$key = array_search($constraint, $fieldNames, true);
235+
236+
if ($key !== false) {
237+
foreach ($values as $arrayKey => $value) {
238+
if (strtoupper($value[$key]) === 'NULL') {
239+
$values[$arrayKey][$key] = 'DEFAULT';
240+
}
241+
}
242+
}
243+
}
244+
245+
$sql = 'INSERT INTO ' . $table . '(' . implode(', ', array_map(static fn ($columnName) => $columnName, $keys)) . ') VALUES ' . implode(', ', $this->getValues($values)) . "\n";
246+
247+
// we can use this sql but maybe we should throw an error here if there are no indexs to update on
248+
if (empty($constraints)) {
249+
return $sql;
250+
}
251+
252+
return $sql .= 'ON CONFLICT("' . implode('","', $constraints) . '") DO UPDATE SET ' . implode(', ', array_map(static fn ($updateField) => '"' . $updateField . '" = "excluded"."' . $updateField . '"', $updateFields));
253+
}
254+
202255
/**
203256
* Compiles a delete string and runs the query
204257
*

0 commit comments

Comments
 (0)