From a49a9542455b93a682d732b048fe11cd3aaa12de Mon Sep 17 00:00:00 2001 From: Luke Towers Date: Mon, 19 Oct 2020 10:58:09 -0600 Subject: [PATCH 1/3] Add support for QueryBuilder upsert() method. Pulls in the work by @paras-malhotra in https://github.com/laravel/framework/pull/34698 & https://github.com/laravel/framework/pull/34712 for use in October CMS. --- src/Database/Builder.php | 75 +++++++++++++++++++ src/Database/Query/Grammars/MySqlGrammar.php | 23 ++++++ .../Query/Grammars/PostgresGrammar.php | 25 +++++++ src/Database/Query/Grammars/SQLiteGrammar.php | 25 +++++++ .../Query/Grammars/SqlServerGrammar.php | 43 +++++++++++ src/Database/QueryBuilder.php | 46 ++++++++++++ 6 files changed, 237 insertions(+) diff --git a/src/Database/Builder.php b/src/Database/Builder.php index 1f5cea9ab..b3f4ce99b 100644 --- a/src/Database/Builder.php +++ b/src/Database/Builder.php @@ -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 diff --git a/src/Database/Query/Grammars/MySqlGrammar.php b/src/Database/Query/Grammars/MySqlGrammar.php index 8a76fcafe..4bcceffe1 100644 --- a/src/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Database/Query/Grammars/MySqlGrammar.php @@ -1,9 +1,32 @@ 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; + } } diff --git a/src/Database/Query/Grammars/PostgresGrammar.php b/src/Database/Query/Grammars/PostgresGrammar.php index 11dac3dcc..3610c3fd1 100644 --- a/src/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Database/Query/Grammars/PostgresGrammar.php @@ -1,9 +1,34 @@ 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; + } } diff --git a/src/Database/Query/Grammars/SQLiteGrammar.php b/src/Database/Query/Grammars/SQLiteGrammar.php index 38929f8ed..89c3b54a1 100644 --- a/src/Database/Query/Grammars/SQLiteGrammar.php +++ b/src/Database/Query/Grammars/SQLiteGrammar.php @@ -1,5 +1,6 @@ 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; + } } diff --git a/src/Database/Query/Grammars/SqlServerGrammar.php b/src/Database/Query/Grammars/SqlServerGrammar.php index 877413567..d8731b2b7 100644 --- a/src/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Database/Query/Grammars/SqlServerGrammar.php @@ -1,9 +1,52 @@ 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; + } } diff --git a/src/Database/QueryBuilder.php b/src/Database/QueryBuilder.php index e811ea630..fce87eae3 100644 --- a/src/Database/QueryBuilder.php +++ b/src/Database/QueryBuilder.php @@ -1,6 +1,7 @@ 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. * From 4e89741660031c6afaf93914a96e84d83ce9997c Mon Sep 17 00:00:00 2001 From: Ben Thomson Date: Tue, 20 Oct 2020 13:13:56 +0800 Subject: [PATCH 2/3] Add unit tests for upsert() query builder method. Based off implementation done in https://github.com/laravel/framework/pull/34698 and https://github.com/laravel/framework/pull/34712. --- composer.json | 5 +- tests/Database/QueryBuilderTest.php | 259 ++++++++++++++++++++++++++++ 2 files changed, 260 insertions(+), 4 deletions(-) create mode 100644 tests/Database/QueryBuilderTest.php diff --git a/composer.json b/composer.json index 8455c1ed1..67b0879a7 100644 --- a/composer.json +++ b/composer.json @@ -88,10 +88,7 @@ "autoload-dev": { "classmap": [ "tests/TestCase.php" - ], - "psr-4": { - "October\\Rain\\Tests\\": "tests/" - } + ] }, "scripts": { "test": [ diff --git a/tests/Database/QueryBuilderTest.php b/tests/Database/QueryBuilderTest.php new file mode 100644 index 000000000..131bc07b6 --- /dev/null +++ b/tests/Database/QueryBuilderTest.php @@ -0,0 +1,259 @@ +getMySqlBuilder() + ->select(['id']) + ->selectConcat(['field', ' ', 'cast'], 'full_cast') + ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); + + $this->assertEquals( + 'select `id`, concat(`field`, \' \', `cast`) as `full_cast`, concat(`field2`, \' \', `cast2`) as `full_cast2`', + $query->toSql() + ); + + $query = $this->getMySqlBuilder() + ->select(['id']) + ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); + + $this->assertEquals( + 'select `id`, concat(\'field\', \' \', `cast`) as `full_cast`', + $query->toSql() + ); + + // SQLite + $query = $this->getSQLiteBuilder() + ->select(['id']) + ->selectConcat(['field', ' ', 'cast'], 'full_cast') + ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); + + $this->assertEquals( + 'select "id", "field" || \' \' || "cast" as "full_cast", "field2" || \' \' || "cast2" as "full_cast2"', + $query->toSql() + ); + + $query = $this->getSQLiteBuilder() + ->select(['id']) + ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); + + $this->assertEquals( + 'select "id", \'field\' || \' \' || "cast" as "full_cast"', + $query->toSql() + ); + + // PostgreSQL + $query = $this->getPostgresBuilder() + ->select(['id']) + ->selectConcat(['field', ' ', 'cast'], 'full_cast') + ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); + + $this->assertEquals( + 'select "id", concat("field", \' \', "cast") as "full_cast", concat("field2", \' \', "cast2") as "full_cast2"', + $query->toSql() + ); + + $query = $this->getPostgresBuilder() + ->select(['id']) + ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); + + $this->assertEquals( + 'select "id", concat(\'field\', \' \', "cast") as "full_cast"', + $query->toSql() + ); + + // SQL Server + $query = $this->getSqlServerBuilder() + ->select(['id']) + ->selectConcat(['field', ' ', 'cast'], 'full_cast') + ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); + + $this->assertEquals( + 'select [id], concat([field], \' \', [cast]) as [full_cast], concat([field2], \' \', [cast2]) as [full_cast2]', + $query->toSql() + ); + + $query = $this->getSqlServerBuilder() + ->select(['id']) + ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); + + $this->assertEquals( + 'select [id], concat(\'field\', \' \', [cast]) as [full_cast]', + $query->toSql() + ); + } + + public function testUpsert() + { + // MySQL + $builder = $this->getMySqlBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into `users` (`email`, `name`) values (?, ?), (?, ?) on duplicate key update `email` = values(`email`), `name` = values(`name`)', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email'); + $this->assertEquals(2, $result); + + // PostgreSQL + $builder = $this->getPostgresBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "email" = "excluded"."email", "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email'); + $this->assertEquals(2, $result); + + // SQLite + $builder = $this->getSQLiteBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "email" = "excluded"."email", "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email'); + $this->assertEquals(2, $result); + + // SQL Server + $builder = $this->getSqlServerBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('merge [users] using (values (?, ?), (?, ?)) [laravel_source] ([email], [name]) on [laravel_source].[email] = [users].[email] when matched then update set [email] = [laravel_source].[email], [name] = [laravel_source].[name] when not matched then insert ([email], [name]) values ([email], [name])', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email'); + $this->assertEquals(2, $result); + } + + public function testUpsertWithUpdateColumns() + { + // MySQL + $builder = $this->getMySqlBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into `users` (`email`, `name`) values (?, ?), (?, ?) on duplicate key update `name` = values(`name`)', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email', ['name']); + $this->assertEquals(2, $result); + + // PostgreSQL + $builder = $this->getPostgresBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email', ['name']); + $this->assertEquals(2, $result); + + // SQLite + $builder = $this->getSQLiteBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('insert into "users" ("email", "name") values (?, ?), (?, ?) on conflict ("email") do update set "name" = "excluded"."name"', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email', ['name']); + $this->assertEquals(2, $result); + + // SQL Server + $builder = $this->getSqlServerBuilder(); + $builder->getConnection() + ->expects($this->once()) + ->method('affectingStatement') + ->with('merge [users] using (values (?, ?), (?, ?)) [laravel_source] ([email], [name]) on [laravel_source].[email] = [users].[email] when matched then update set [name] = [laravel_source].[name] when not matched then insert ([email], [name]) values ([email], [name])', ['foo', 'bar', 'foo2', 'bar2']) + ->willReturn(2); + $result = $builder->from('users')->upsert([['email' => 'foo', 'name' => 'bar'], ['name' => 'bar2', 'email' => 'foo2']], 'email', ['name']); + $this->assertEquals(2, $result); + } + + protected function getConnection() + { + $connection = $this->getMockBuilder(ConnectionInterface::class) + ->disableOriginalConstructor() + ->disableOriginalClone() + ->disableArgumentCloning() + ->disallowMockingUnknownTypes() + ->setMethods([ + 'table', + 'raw', + 'selectOne', + 'select', + 'cursor', + 'insert', + 'update', + 'delete', + 'statement', + 'affectingStatement', + 'unprepared', + 'prepareBindings', + 'transaction', + 'beginTransaction', + 'commit', + 'rollBack', + 'transactionLevel', + 'pretend', + ]) + ->addMethods([ + 'getDatabaseName', + ]) + ->getMock(); + + $connection->method('getDatabaseName')->willReturn('database'); + + return $connection; + } + + protected function getBuilder() + { + $grammar = new Grammar; + $processor = $this->createMock(Processor::class); + + return new QueryBuilder($this->getConnection(), $grammar, $processor); + } + + protected function getMySqlBuilder() + { + $grammar = new MySqlGrammar; + $processor = $this->createMock(Processor::class); + + return new QueryBuilder($this->getConnection(), $grammar, $processor); + } + + protected function getPostgresBuilder() + { + $grammar = new PostgresGrammar; + $processor = $this->createMock(Processor::class); + + return new QueryBuilder($this->getConnection(), $grammar, $processor); + } + + protected function getSQLiteBuilder() + { + $grammar = new SQLiteGrammar; + $processor = $this->createMock(Processor::class); + + return new QueryBuilder($this->getConnection(), $grammar, $processor); + } + + protected function getSqlServerBuilder() + { + $grammar = new SqlServerGrammar; + $processor = $this->createMock(Processor::class); + + return new QueryBuilder($this->getConnection(), $grammar, $processor); + } +} \ No newline at end of file From ffefe5189691bc5e5177e05be28de6065ae128d3 Mon Sep 17 00:00:00 2001 From: Ben Thomson Date: Tue, 20 Oct 2020 13:15:10 +0800 Subject: [PATCH 3/3] Drop separate selectConcat() method tests --- tests/Database/QueryBuilderTest.php | 2 +- tests/Database/SelectConcatTest.php | 145 ---------------------------- 2 files changed, 1 insertion(+), 146 deletions(-) delete mode 100644 tests/Database/SelectConcatTest.php diff --git a/tests/Database/QueryBuilderTest.php b/tests/Database/QueryBuilderTest.php index 131bc07b6..2361e7cf7 100644 --- a/tests/Database/QueryBuilderTest.php +++ b/tests/Database/QueryBuilderTest.php @@ -256,4 +256,4 @@ protected function getSqlServerBuilder() return new QueryBuilder($this->getConnection(), $grammar, $processor); } -} \ No newline at end of file +} diff --git a/tests/Database/SelectConcatTest.php b/tests/Database/SelectConcatTest.php deleted file mode 100644 index 889ed9603..000000000 --- a/tests/Database/SelectConcatTest.php +++ /dev/null @@ -1,145 +0,0 @@ -addConnection([ - 'driver' => 'mysql', - 'database' => ':memory:', - 'prefix' => '' - ]); - $capsule->setAsGlobal(); - $capsule->bootEloquent(); - - $model = new Revision; - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['field', ' ', 'cast'], 'full_cast') - ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); - - $this->assertEquals( - 'select `id`, concat(`field`, \' \', `cast`) as `full_cast`, concat(`field2`, \' \', `cast2`) as `full_cast2` from `revisions`', - $query->toSql() - ); - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); - - $this->assertEquals( - 'select `id`, concat(\'field\', \' \', `cast`) as `full_cast` from `revisions`', - $query->toSql() - ); - } - - public function testSQLiteConcat() - { - $capsule = new October\Rain\Database\Capsule\Manager; - $capsule->addConnection([ - 'driver' => 'sqlite', - 'database' => ':memory:', - 'prefix' => '' - ]); - $capsule->setAsGlobal(); - $capsule->bootEloquent(); - - $model = new Revision; - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['field', ' ', 'cast'], 'full_cast') - ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); - - $this->assertEquals( - 'select "id", "field" || \' \' || "cast" as "full_cast", "field2" || \' \' || "cast2" as "full_cast2" from "revisions"', - $query->toSql() - ); - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); - - $this->assertEquals( - 'select "id", \'field\' || \' \' || "cast" as "full_cast" from "revisions"', - $query->toSql() - ); - } - - public function testPostgresqlConcat() - { - $capsule = new October\Rain\Database\Capsule\Manager; - $capsule->addConnection([ - 'driver' => 'pgsql', - 'database' => ':memory:', - 'prefix' => '' - ]); - $capsule->setAsGlobal(); - $capsule->bootEloquent(); - - $model = new Revision; - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['field', ' ', 'cast'], 'full_cast') - ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); - - $this->assertEquals( - 'select "id", concat("field", \' \', "cast") as "full_cast", concat("field2", \' \', "cast2") as "full_cast2" from "revisions"', - $query->toSql() - ); - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); - - $this->assertEquals( - 'select "id", concat(\'field\', \' \', "cast") as "full_cast" from "revisions"', - $query->toSql() - ); - } - - public function testSqlServerConcat() - { - $capsule = new October\Rain\Database\Capsule\Manager; - $capsule->addConnection([ - 'driver' => 'sqlsrv', - 'database' => ':memory:', - 'prefix' => '' - ]); - $capsule->setAsGlobal(); - $capsule->bootEloquent(); - - $model = new Revision; - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['field', ' ', 'cast'], 'full_cast') - ->selectConcat(['field2', ' ', 'cast2'], 'full_cast2'); - - $this->assertEquals( - 'select [id], concat([field], \' \', [cast]) as [full_cast], concat([field2], \' \', [cast2]) as [full_cast2] from [revisions]', - $query->toSql() - ); - - $query = $model - ->newQuery() - ->select(['id']) - ->selectConcat(['"field"', ' ', 'cast'], 'full_cast'); - - $this->assertEquals( - 'select [id], concat(\'field\', \' \', [cast]) as [full_cast] from [revisions]', - $query->toSql() - ); - } -}