Skip to content

Commit a49a954

Browse files
author
Luke Towers
committed
Add support for QueryBuilder upsert() method.
Pulls in the work by @paras-malhotra in laravel/framework#34698 & laravel/framework#34712 for use in October CMS.
1 parent d72caf0 commit a49a954

File tree

6 files changed

+237
-0
lines changed

6 files changed

+237
-0
lines changed

src/Database/Builder.php

Lines changed: 75 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -185,6 +185,81 @@ public function simplePaginate($perPage = null, $currentPage = null, $columns =
185185
]);
186186
}
187187

188+
/**
189+
* Insert new records or update the existing ones.
190+
*
191+
* @param array $values
192+
* @param array|string $uniqueBy
193+
* @param array|null $update
194+
* @return int
195+
*/
196+
public function upsert(array $values, $uniqueBy, $update = null)
197+
{
198+
if (empty($values)) {
199+
return 0;
200+
}
201+
202+
if (!is_array(reset($values))) {
203+
$values = [$values];
204+
}
205+
206+
if (is_null($update)) {
207+
$update = array_keys(reset($values));
208+
}
209+
210+
$values = $this->addTimestampsToValues($values);
211+
212+
$update = $this->addUpdatedAtToColumns($update);
213+
214+
return $this->toBase()->upsert($values, $uniqueBy, $update);
215+
}
216+
217+
/**
218+
* Add timestamps to the inserted values.
219+
*
220+
* @param array $values
221+
* @return array
222+
*/
223+
protected function addTimestampsToValues(array $values)
224+
{
225+
if (!$this->model->usesTimestamps()) {
226+
return $values;
227+
}
228+
229+
$timestamp = $this->model->freshTimestampString();
230+
231+
$columns = array_filter([$this->model->getCreatedAtColumn(), $this->model->getUpdatedAtColumn()]);
232+
233+
foreach ($columns as $column) {
234+
foreach ($values as &$row) {
235+
$row = array_merge([$column => $timestamp], $row);
236+
}
237+
}
238+
239+
return $values;
240+
}
241+
242+
/**
243+
* Add the "updated at" column to the updated columns.
244+
*
245+
* @param array $update
246+
* @return array
247+
*/
248+
protected function addUpdatedAtToColumns(array $update)
249+
{
250+
if (!$this->model->usesTimestamps()) {
251+
return $update;
252+
}
253+
254+
$column = $this->model->getUpdatedAtColumn();
255+
256+
if (!is_null($column) && !array_key_exists($column, $update) && !in_array($column, $update)) {
257+
$update[] = $column;
258+
}
259+
260+
return $update;
261+
}
262+
188263
/**
189264
* Dynamically handle calls into the query instance.
190265
* @param string $method
Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,32 @@
11
<?php namespace October\Rain\Database\Query\Grammars;
22

3+
use October\Rain\Database\QueryBuilder;
34
use Illuminate\Database\Query\Grammars\MySqlGrammar as BaseMysqlGrammer;
45
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;
56

67
class MySqlGrammar extends BaseMysqlGrammer
78
{
89
use SelectConcatenations;
10+
11+
/**
12+
* Compile an "upsert" statement into SQL.
13+
*
14+
* @param \October\Rain\Database\QueryBuilder $query
15+
* @param array $values
16+
* @param array $uniqueBy
17+
* @param array $update
18+
* @return string
19+
*/
20+
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
21+
{
22+
$sql = $this->compileInsert($query, $values) . ' on duplicate key update ';
23+
24+
$columns = collect($update)->map(function ($value, $key) {
25+
return is_numeric($key)
26+
? $this->wrap($value) . ' = values(' . $this->wrap($value) . ')'
27+
: $this->wrap($key) . ' = ' . $this->parameter($value);
28+
})->implode(', ');
29+
30+
return $sql . $columns;
31+
}
932
}
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,34 @@
11
<?php namespace October\Rain\Database\Query\Grammars;
22

3+
use October\Rain\Database\QueryBuilder;
34
use Illuminate\Database\Query\Grammars\PostgresGrammar as BasePostgresGrammer;
45
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;
56

67
class PostgresGrammar extends BasePostgresGrammer
78
{
89
use SelectConcatenations;
10+
11+
/**
12+
* Compile an "upsert" statement into SQL.
13+
*
14+
* @param \October\Rain\Database\QueryBuilder $query
15+
* @param array $values
16+
* @param array $uniqueBy
17+
* @param array $update
18+
* @return string
19+
*/
20+
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
21+
{
22+
$sql = $this->compileInsert($query, $values);
23+
24+
$sql .= ' on conflict (' . $this->columnize($uniqueBy) . ') do update set ';
25+
26+
$columns = collect($update)->map(function ($value, $key) {
27+
return is_numeric($key)
28+
? $this->wrap($value) . ' = ' . $this->wrapValue('excluded') . '.' . $this->wrap($value)
29+
: $this->wrap($key) . ' = ' . $this->parameter($value);
30+
})->implode(', ');
31+
32+
return $sql . $columns;
33+
}
934
}

src/Database/Query/Grammars/SQLiteGrammar.php

Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
<?php namespace October\Rain\Database\Query\Grammars;
22

3+
use October\Rain\Database\QueryBuilder;
34
use Illuminate\Database\Query\Expression;
45
use Illuminate\Database\Query\Grammars\SQLiteGrammar as BaseSQLiteGrammar;
56
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;
@@ -31,4 +32,28 @@ protected function compileConcat(array $parts, string $as)
3132

3233
return implode(' || ', $compileParts) . ' as ' . $this->wrap($as);
3334
}
35+
36+
/**
37+
* Compile an "upsert" statement into SQL.
38+
*
39+
* @param \October\Rain\Database\QueryBuilder $query
40+
* @param array $values
41+
* @param array $uniqueBy
42+
* @param array $update
43+
* @return string
44+
*/
45+
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
46+
{
47+
$sql = $this->compileInsert($query, $values);
48+
49+
$sql .= ' on conflict (' . $this->columnize($uniqueBy) . ') do update set ';
50+
51+
$columns = collect($update)->map(function ($value, $key) {
52+
return is_numeric($key)
53+
? $this->wrap($value) . ' = ' . $this->wrapValue('excluded') . '.' . $this->wrap($value)
54+
: $this->wrap($key) . ' = ' . $this->parameter($value);
55+
})->implode(', ');
56+
57+
return $sql . $columns;
58+
}
3459
}
Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,52 @@
11
<?php namespace October\Rain\Database\Query\Grammars;
22

3+
use October\Rain\Database\QueryBuilder;
34
use Illuminate\Database\Query\Grammars\SqlServerGrammar as BaseSqlServerGrammar;
45
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;
56

67
class SqlServerGrammar extends BaseSqlServerGrammar
78
{
89
use SelectConcatenations;
10+
11+
/**
12+
* Compile an "upsert" statement into SQL.
13+
*
14+
* @param \October\Rain\Database\QueryBuilder $query
15+
* @param array $values
16+
* @param array $uniqueBy
17+
* @param array $update
18+
* @return string
19+
*/
20+
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
21+
{
22+
$columns = $this->columnize(array_keys(reset($values)));
23+
24+
$sql = 'merge ' . $this->wrapTable($query->from) . ' ';
25+
26+
$parameters = collect($values)->map(function ($record) {
27+
return '(' . $this->parameterize($record) . ')';
28+
})->implode(', ');
29+
30+
$sql .= 'using (values ' . $parameters . ') ' . $this->wrapTable('laravel_source') . ' (' . $columns . ') ';
31+
32+
$on = collect($uniqueBy)->map(function ($column) use ($query) {
33+
return $this->wrap('laravel_source.' . $column) . ' = ' . $this->wrap($query->from . '.' . $column);
34+
})->implode(' and ');
35+
36+
$sql .= 'on ' . $on . ' ';
37+
38+
if ($update) {
39+
$update = collect($update)->map(function ($value, $key) {
40+
return is_numeric($key)
41+
? $this->wrap($value) . ' = ' . $this->wrap('laravel_source.' . $value)
42+
: $this->wrap($key) . ' = ' . $this->parameter($value);
43+
})->implode(', ');
44+
45+
$sql .= 'when matched then update set ' . $update . ' ';
46+
}
47+
48+
$sql .= 'when not matched then insert (' . $columns . ') values (' . $columns . ')';
49+
50+
return $sql;
51+
}
952
}

src/Database/QueryBuilder.php

Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,7 @@
11
<?php namespace October\Rain\Database;
22

33
use App;
4+
use October\Rain\Support\Arr;
45
use Illuminate\Database\Query\Builder as QueryBuilderBase;
56

67
class QueryBuilder extends QueryBuilderBase
@@ -303,6 +304,51 @@ public function insert(array $values)
303304
return parent::insert($values);
304305
}
305306

307+
/**
308+
* Insert new records or update the existing ones.
309+
*
310+
* @param array $values
311+
* @param array|string $uniqueBy
312+
* @param array|null $update
313+
* @return int
314+
*/
315+
public function upsert(array $values, $uniqueBy, $update = null)
316+
{
317+
if (empty($values)) {
318+
return 0;
319+
}
320+
321+
if ($update === []) {
322+
return (int) $this->insert($values);
323+
}
324+
325+
if (!is_array(reset($values))) {
326+
$values = [$values];
327+
} else {
328+
foreach ($values as $key => $value) {
329+
ksort($value);
330+
331+
$values[$key] = $value;
332+
}
333+
}
334+
335+
if (is_null($update)) {
336+
$update = array_keys(reset($values));
337+
}
338+
339+
$bindings = $this->cleanBindings(array_merge(
340+
Arr::flatten($values, 1),
341+
collect($update)->reject(function ($value, $key) {
342+
return is_int($key);
343+
})->all()
344+
));
345+
346+
return $this->connection->affectingStatement(
347+
$this->grammar->compileUpsert($this, $values, (array) $uniqueBy, $update),
348+
$bindings
349+
);
350+
}
351+
306352
/**
307353
* Run a truncate statement on the table.
308354
*

0 commit comments

Comments
 (0)