Skip to content
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

Add support for QueryBuilder upsert() method. #531

Merged
merged 3 commits into from
Oct 20, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
5 changes: 1 addition & 4 deletions composer.json
Original file line number Diff line number Diff line change
Expand Up @@ -88,10 +88,7 @@
"autoload-dev": {
"classmap": [
"tests/TestCase.php"
],
"psr-4": {
"October\\Rain\\Tests\\": "tests/"
}
]
},
"scripts": {
"test": [
Expand Down
75 changes: 75 additions & 0 deletions src/Database/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -185,6 +185,81 @@ public function simplePaginate($perPage = null, $currentPage = null, $columns =
]);
}

/**
* Insert new records or update the existing ones.
*
* @param array $values
* @param array|string $uniqueBy
* @param array|null $update
* @return int
*/
public function upsert(array $values, $uniqueBy, $update = null)
{
if (empty($values)) {
return 0;
}

if (!is_array(reset($values))) {
$values = [$values];
}

if (is_null($update)) {
$update = array_keys(reset($values));
}

$values = $this->addTimestampsToValues($values);

$update = $this->addUpdatedAtToColumns($update);

return $this->toBase()->upsert($values, $uniqueBy, $update);
}

/**
* Add timestamps to the inserted values.
*
* @param array $values
* @return array
*/
protected function addTimestampsToValues(array $values)
{
if (!$this->model->usesTimestamps()) {
return $values;
}

$timestamp = $this->model->freshTimestampString();

$columns = array_filter([$this->model->getCreatedAtColumn(), $this->model->getUpdatedAtColumn()]);

foreach ($columns as $column) {
foreach ($values as &$row) {
$row = array_merge([$column => $timestamp], $row);
}
}

return $values;
}

/**
* Add the "updated at" column to the updated columns.
*
* @param array $update
* @return array
*/
protected function addUpdatedAtToColumns(array $update)
{
if (!$this->model->usesTimestamps()) {
return $update;
}

$column = $this->model->getUpdatedAtColumn();

if (!is_null($column) && !array_key_exists($column, $update) && !in_array($column, $update)) {
$update[] = $column;
}

return $update;
}

/**
* Dynamically handle calls into the query instance.
* @param string $method
Expand Down
23 changes: 23 additions & 0 deletions src/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
@@ -1,9 +1,32 @@
<?php namespace October\Rain\Database\Query\Grammars;

use October\Rain\Database\QueryBuilder;
use Illuminate\Database\Query\Grammars\MySqlGrammar as BaseMysqlGrammer;
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;

class MySqlGrammar extends BaseMysqlGrammer
{
use SelectConcatenations;

/**
* Compile an "upsert" statement into SQL.
*
* @param \October\Rain\Database\QueryBuilder $query
* @param array $values
* @param array $uniqueBy
* @param array $update
* @return string
*/
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
{
$sql = $this->compileInsert($query, $values) . ' on duplicate key update ';

$columns = collect($update)->map(function ($value, $key) {
return is_numeric($key)
? $this->wrap($value) . ' = values(' . $this->wrap($value) . ')'
: $this->wrap($key) . ' = ' . $this->parameter($value);
})->implode(', ');

return $sql . $columns;
}
}
25 changes: 25 additions & 0 deletions src/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
@@ -1,9 +1,34 @@
<?php namespace October\Rain\Database\Query\Grammars;

use October\Rain\Database\QueryBuilder;
use Illuminate\Database\Query\Grammars\PostgresGrammar as BasePostgresGrammer;
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;

class PostgresGrammar extends BasePostgresGrammer
{
use SelectConcatenations;

/**
* Compile an "upsert" statement into SQL.
*
* @param \October\Rain\Database\QueryBuilder $query
* @param array $values
* @param array $uniqueBy
* @param array $update
* @return string
*/
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
{
$sql = $this->compileInsert($query, $values);

$sql .= ' on conflict (' . $this->columnize($uniqueBy) . ') do update set ';

$columns = collect($update)->map(function ($value, $key) {
return is_numeric($key)
? $this->wrap($value) . ' = ' . $this->wrapValue('excluded') . '.' . $this->wrap($value)
: $this->wrap($key) . ' = ' . $this->parameter($value);
})->implode(', ');

return $sql . $columns;
}
}
25 changes: 25 additions & 0 deletions src/Database/Query/Grammars/SQLiteGrammar.php
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
<?php namespace October\Rain\Database\Query\Grammars;

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

return implode(' || ', $compileParts) . ' as ' . $this->wrap($as);
}

/**
* Compile an "upsert" statement into SQL.
*
* @param \October\Rain\Database\QueryBuilder $query
* @param array $values
* @param array $uniqueBy
* @param array $update
* @return string
*/
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
{
$sql = $this->compileInsert($query, $values);

$sql .= ' on conflict (' . $this->columnize($uniqueBy) . ') do update set ';

$columns = collect($update)->map(function ($value, $key) {
return is_numeric($key)
? $this->wrap($value) . ' = ' . $this->wrapValue('excluded') . '.' . $this->wrap($value)
: $this->wrap($key) . ' = ' . $this->parameter($value);
})->implode(', ');

return $sql . $columns;
}
}
43 changes: 43 additions & 0 deletions src/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
@@ -1,9 +1,52 @@
<?php namespace October\Rain\Database\Query\Grammars;

use October\Rain\Database\QueryBuilder;
use Illuminate\Database\Query\Grammars\SqlServerGrammar as BaseSqlServerGrammar;
use October\Rain\Database\Query\Grammars\Concerns\SelectConcatenations;

class SqlServerGrammar extends BaseSqlServerGrammar
{
use SelectConcatenations;

/**
* Compile an "upsert" statement into SQL.
*
* @param \October\Rain\Database\QueryBuilder $query
* @param array $values
* @param array $uniqueBy
* @param array $update
* @return string
*/
public function compileUpsert(QueryBuilder $query, array $values, array $uniqueBy, array $update)
{
$columns = $this->columnize(array_keys(reset($values)));

$sql = 'merge ' . $this->wrapTable($query->from) . ' ';

$parameters = collect($values)->map(function ($record) {
return '(' . $this->parameterize($record) . ')';
})->implode(', ');

$sql .= 'using (values ' . $parameters . ') ' . $this->wrapTable('laravel_source') . ' (' . $columns . ') ';

$on = collect($uniqueBy)->map(function ($column) use ($query) {
return $this->wrap('laravel_source.' . $column) . ' = ' . $this->wrap($query->from . '.' . $column);
})->implode(' and ');

$sql .= 'on ' . $on . ' ';

if ($update) {
$update = collect($update)->map(function ($value, $key) {
return is_numeric($key)
? $this->wrap($value) . ' = ' . $this->wrap('laravel_source.' . $value)
: $this->wrap($key) . ' = ' . $this->parameter($value);
})->implode(', ');

$sql .= 'when matched then update set ' . $update . ' ';
}

$sql .= 'when not matched then insert (' . $columns . ') values (' . $columns . ')';

return $sql;
}
}
46 changes: 46 additions & 0 deletions src/Database/QueryBuilder.php
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
<?php namespace October\Rain\Database;

use App;
use October\Rain\Support\Arr;
use Illuminate\Database\Query\Builder as QueryBuilderBase;

class QueryBuilder extends QueryBuilderBase
Expand Down Expand Up @@ -303,6 +304,51 @@ public function insert(array $values)
return parent::insert($values);
}

/**
* Insert new records or update the existing ones.
*
* @param array $values
* @param array|string $uniqueBy
* @param array|null $update
* @return int
*/
public function upsert(array $values, $uniqueBy, $update = null)
{
if (empty($values)) {
return 0;
}

if ($update === []) {
return (int) $this->insert($values);
}

if (!is_array(reset($values))) {
$values = [$values];
} else {
foreach ($values as $key => $value) {
ksort($value);

$values[$key] = $value;
}
}

if (is_null($update)) {
$update = array_keys(reset($values));
}

$bindings = $this->cleanBindings(array_merge(
Arr::flatten($values, 1),
collect($update)->reject(function ($value, $key) {
return is_int($key);
})->all()
));

return $this->connection->affectingStatement(
$this->grammar->compileUpsert($this, $values, (array) $uniqueBy, $update),
$bindings
);
}

/**
* Run a truncate statement on the table.
*
Expand Down
Loading