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

[8.x] Add upsert to Eloquent and Base Query Builders #34698

Merged
merged 3 commits into from Oct 6, 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.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
14 changes: 14 additions & 0 deletions src/Illuminate/Database/Eloquent/Builder.php
Expand Up @@ -800,6 +800,20 @@ public function update(array $values)
return $this->toBase()->update($this->addUpdatedAtColumn($values));
}

/**
* Insert new records or update the existing ones.
*
* @param array $values
* @param array|string $uniqueBy
* @return int
*/
public function upsert(array $values, $uniqueBy)
{
return $this->toBase()->upsert(collect($values)->map(function ($value, $key) {
return $this->addUpdatedAtColumn($value);
})->toArray(), $uniqueBy);
}

/**
* Increment a column's value by a given amount.
*
Expand Down
29 changes: 29 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Expand Up @@ -2923,6 +2923,35 @@ public function updateOrInsert(array $attributes, array $values = [])
return (bool) $this->limit(1)->update($values);
}

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

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

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

return $this->connection->affectingStatement(
$this->grammar->compileUpsert($this, $values, (array) $uniqueBy),
$this->cleanBindings(Arr::flatten($values, 1))
);
}

/**
* Increment a column's value by a given amount.
*
Expand Down
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Expand Up @@ -995,6 +995,21 @@ protected function compileUpdateWithJoins(Builder $query, $table, $columns, $whe
return "update {$table} {$joins} set {$columns} {$where}";
}

/**
* Compile an "upsert" statement into SQL.
*
* @param \Illuminate\Database\Query\Builder $query
* @param array $values
* @param array $uniqueBy
* @return string
*
* @throws \RuntimeException
*/
public function compileUpsert(Builder $query, array $values, array $uniqueBy)
{
throw new RuntimeException('This database engine does not support upserts.');
}

/**
* Prepare the bindings for an update statement.
*
Expand Down
19 changes: 19 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Expand Up @@ -153,6 +153,25 @@ protected function compileUpdateColumns(Builder $query, array $values)
})->implode(', ');
}

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

$columns = collect(array_keys(reset($values)))->map(function ($value, $key) {
return $this->wrap($value).' = values('.$this->wrap($value).')';
})->implode(', ');

return $sql.$columns;
}

/**
* Prepare a JSON column being updated using the JSON_SET function.
*
Expand Down
21 changes: 21 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Expand Up @@ -218,6 +218,27 @@ protected function compileUpdateColumns(Builder $query, array $values)
})->implode(', ');
}

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

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

$columns = collect(array_keys(reset($values)))->map(function ($value, $key) {
return $this->wrap($value).' = '.$this->wrapValue('excluded').'.'.$this->wrap($value);
})->implode(', ');

return $sql.$columns;
}

/**
* Prepares a JSON column being updated using the JSONB_SET function.
*
Expand Down
21 changes: 21 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php
Expand Up @@ -182,6 +182,27 @@ protected function compileUpdateColumns(Builder $query, array $values)
})->implode(', ');
}

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

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

$columns = collect(array_keys(reset($values)))->map(function ($value, $key) {
return $this->wrap($value).' = '.$this->wrapValue('excluded').'.'.$this->wrap($value);
})->implode(', ');

return $sql.$columns;
}

/**
* Group the nested JSON columns.
*
Expand Down
31 changes: 31 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Expand Up @@ -341,6 +341,37 @@ protected function compileUpdateWithJoins(Builder $query, $table, $columns, $whe
return "update {$alias} set {$columns} from {$table} {$joins} {$where}";
}

/**
* Compile an "upsert" statement into SQL.
*
* @param \Illuminate\Database\Query\Builder $query
* @param array $values
* @param array $uniqueBy
* @return string
*/
public function compileUpsert(Builder $query, array $values, array $uniqueBy)
{
$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.' ';

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

return $sql;
}

/**
* Prepare the bindings for an update statement.
*
Expand Down
23 changes: 23 additions & 0 deletions tests/Database/DatabaseEloquentBuilderTest.php
Expand Up @@ -1315,6 +1315,29 @@ public function testUpdateWithAlias()
Carbon::setTestNow(null);
}

public function testUpsert()
{
Carbon::setTestNow($now = '2017-10-10 10:10:10');

$query = m::mock(BaseBuilder::class);
$query->shouldReceive('from')->with('foo_table')->andReturn('foo_table');
$query->from = 'foo_table';

$builder = new Builder($query);
$model = new EloquentBuilderTestStubStringPrimaryKey;
$builder->setModel($model);

$query->shouldReceive('upsert')->once()
->with([
['email' => 'foo', 'name' => 'bar', 'foo_table.updated_at' => $now],
['name' => 'bar2', 'email' => 'foo2', 'foo_table.updated_at' => $now], ], 'email')->andReturn(2);

$result = $builder->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email');
$this->assertEquals(2, $result);

Carbon::setTestNow(null);
}

public function testWithCastsMethod()
{
$builder = new Builder($this->getMockQueryBuilder());
Expand Down
23 changes: 23 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Expand Up @@ -2188,6 +2188,29 @@ public function testUpdateMethod()
$this->assertEquals(1, $result);
}

public function testUpsertMethod()
{
$builder = $this->getMySqlBuilder();
$builder->getConnection()->shouldReceive('affectingStatement')->once()->with('insert into `users` (`email`, `name`) values (?, ?), (?, ?) on duplicate key update `email` = values(`email`), `name` = values(`name`)', ['foo', 'bar', 'foo2', 'bar2'])->andReturn(2);
$result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email');
$this->assertEquals(2, $result);

$builder = $this->getPostgresBuilder();
$builder->getConnection()->shouldReceive('affectingStatement')->once()->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "email" = "excluded"."email", "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2'])->andReturn(2);
$result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email');
$this->assertEquals(2, $result);

$builder = $this->getSQLiteBuilder();
$builder->getConnection()->shouldReceive('affectingStatement')->once()->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "email" = "excluded"."email", "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2'])->andReturn(2);
$result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email');
$this->assertEquals(2, $result);

$builder = $this->getSqlServerBuilder();
$builder->getConnection()->shouldReceive('affectingStatement')->once()->with('merge [users] using (values (?, ?), (?, ?)) [laravel_source] ([email], [name]) on [laravel_source].[email] = [users].[email] when not matched then insert ([email], [name]) values ([email], [name])', ['foo', 'bar', 'foo2', 'bar2'])->andReturn(2);
$result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email');
$this->assertEquals(2, $result);
}

public function testUpdateMethodWithJoins()
{
$builder = $this->getBuilder();
Expand Down