From e7aa0e9785214aaeefb3c2822e35b84a2d944ba5 Mon Sep 17 00:00:00 2001 From: Eder Soares Date: Wed, 20 Feb 2019 00:51:18 -0300 Subject: [PATCH 1/4] Improve union all queries in Postgres grammar --- .../Query/Grammars/PostgresGrammar.php | 53 +++++++++++++++++++ 1 file changed, 53 insertions(+) diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index be5b882d6ac6..b3f8b477b978 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -8,6 +8,25 @@ class PostgresGrammar extends Grammar { + /** + * The components that make up a select clause. + * + * @var array + */ + protected $selectComponents = [ + 'aggregate', + 'columns', + 'from', + 'joins', + 'wheres', + 'groups', + 'havings', + 'orders', + 'limit', + 'offset', + 'lock', + ]; + /** * All of the available clause operators. * @@ -85,6 +104,40 @@ protected function dateBasedWhere($type, Builder $query, $where) return 'extract('.$type.' from '.$this->wrap($where['column']).') '.$where['operator'].' '.$value; } + /** + * Compile a select query into SQL. + * + * @param \Illuminate\Database\Query\Builder $query + * @return string + */ + public function compileSelect(Builder $query) + { + if ($query->unions && $query->aggregate) { + return $this->compileUnionAggregate($query); + } + + $sql = parent::compileSelect($query); + + if ($query->unions) { + $sql = '('.$sql.') '.$this->compileUnions($query); + } + + return $sql; + } + + /** + * Compile a single union statement. + * + * @param array $union + * @return string + */ + protected function compileUnion(array $union) + { + $conjunction = $union['all'] ? ' union all ' : ' union '; + + return $conjunction.'('.$union['query']->toSql().')'; + } + /** * Compile a "JSON contains" statement into SQL. * From c8e110725ba5f37280b72fe1b3aa33b55c24dd2b Mon Sep 17 00:00:00 2001 From: Eder Soares Date: Wed, 20 Feb 2019 01:00:10 -0300 Subject: [PATCH 2/4] Fix testUnionAggregate() for Postgres query builder --- tests/Database/DatabaseQueryBuilderTest.php | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index f671c5527133..59e5c272d098 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -873,7 +873,7 @@ public function testUnionAggregate() $builder->getProcessor()->shouldReceive('processSelect')->once(); $builder->from('posts')->select('id')->union($this->getMySqlBuilder()->from('videos')->select('id'))->count(); - $expected = 'select count(*) as aggregate from (select * from "posts" union select * from "videos") as "temp_table"'; + $expected = 'select count(*) as aggregate from ((select * from "posts") union (select * from "videos")) as "temp_table"'; $builder = $this->getPostgresBuilder(); $builder->getConnection()->shouldReceive('select')->once()->with($expected, [], true); $builder->getProcessor()->shouldReceive('processSelect')->once(); From 06d37a4ee79da306d30f7daa89a612a3f859b34a Mon Sep 17 00:00:00 2001 From: Eder Soares Date: Wed, 20 Feb 2019 01:02:05 -0300 Subject: [PATCH 3/4] Add union with limit and offset test for Postgres --- tests/Database/DatabaseQueryBuilderTest.php | 14 ++++++++++++++ 1 file changed, 14 insertions(+) diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 59e5c272d098..62ac61d4684f 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -826,6 +826,20 @@ public function testUnionLimitsAndOffsets() $builder->union($this->getBuilder()->select('*')->from('dogs')); $builder->skip(5)->take(10); $this->assertEquals('select * from "users" union select * from "dogs" limit 10 offset 5', $builder->toSql()); + + $expectedSql = '(select * from "users") union (select * from "dogs") limit 10 offset 5'; + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users'); + $builder->union($this->getBuilder()->select('*')->from('dogs')); + $builder->skip(5)->take(10); + $this->assertEquals($expectedSql, $builder->toSql()); + + $expectedSql = '(select * from "users" limit 11) union (select * from "dogs" limit 22) limit 10 offset 5'; + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->limit(11); + $builder->union($this->getBuilder()->select('*')->from('dogs')->limit(22)); + $builder->skip(5)->take(10); + $this->assertEquals($expectedSql, $builder->toSql()); } public function testUnionWithJoin() From c821cbf6f20fca4c50aa9d8fb08f71425afc07b8 Mon Sep 17 00:00:00 2001 From: Eder Soares Date: Wed, 20 Feb 2019 01:03:09 -0300 Subject: [PATCH 4/4] Add union and union all tests for Postgres --- tests/Database/DatabaseQueryBuilderTest.php | 14 ++++++++++++++ 1 file changed, 14 insertions(+) diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 62ac61d4684f..4d94cadd3038 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -772,6 +772,13 @@ public function testUnions() $this->assertEquals($expectedSql, $builder->toSql()); $this->assertEquals([0 => 10, 1 => 1, 2 => 11, 3 => 2], $builder->getBindings()); + $builder = $this->getPostgresBuilder(); + $expectedSql = '(select "name" from "users" where "id" = ?) union (select "name" from "users" where "id" = ?)'; + $builder->select('name')->from('users')->where('id', '=', 1); + $builder->union($this->getPostgresBuilder()->select('name')->from('users')->where('id', '=', 2)); + $this->assertEquals($expectedSql, $builder->toSql()); + $this->assertEquals([0 => 1, 1 => 2], $builder->getBindings()); + $builder = $this->getSQLiteBuilder(); $expectedSql = 'select * from (select "name" from "users" where "id" = ?) union select * from (select "name" from "users" where "id" = ?)'; $builder->select('name')->from('users')->where('id', '=', 1); @@ -787,6 +794,13 @@ public function testUnionAlls() $builder->unionAll($this->getBuilder()->select('*')->from('users')->where('id', '=', 2)); $this->assertEquals('select * from "users" where "id" = ? union all select * from "users" where "id" = ?', $builder->toSql()); $this->assertEquals([0 => 1, 1 => 2], $builder->getBindings()); + + $expectedSql = '(select * from "users" where "id" = ?) union all (select * from "users" where "id" = ?)'; + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1); + $builder->unionAll($this->getBuilder()->select('*')->from('users')->where('id', '=', 2)); + $this->assertEquals($expectedSql, $builder->toSql()); + $this->assertEquals([0 => 1, 1 => 2], $builder->getBindings()); } public function testMultipleUnions()