From 6a491c24df29a5d70946ecc5c0e9d26446841e41 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?J=C3=A9r=C3=B4me=20Tamarelle?= Date: Mon, 18 Nov 2024 23:11:56 +0100 Subject: [PATCH] [11.x] Support DB aggregate by group (#53209) * Support aggregation by group * Support group aggregate with union * Change return type of all aggregate functions * Fix CS * formatting --------- Co-authored-by: Taylor Otwell --- src/Illuminate/Database/Query/Builder.php | 22 ++++-- .../Database/Query/Grammars/Grammar.php | 14 +++- tests/Database/DatabaseQueryBuilderTest.php | 76 +++++++++++++++++++ 3 files changed, 102 insertions(+), 10 deletions(-) diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 66f18f4eee60..db35f79adec1 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -3554,18 +3554,20 @@ public function doesntExistOr(Closure $callback) * Retrieve the "count" result of the query. * * @param \Illuminate\Contracts\Database\Query\Expression|string $columns - * @return int + * @return \Illuminate\Support\Collection|int */ public function count($columns = '*') { - return (int) $this->aggregate(__FUNCTION__, Arr::wrap($columns)); + $results = $this->aggregate(__FUNCTION__, Arr::wrap($columns)); + + return $results instanceof Collection ? $results : (int) $results; } /** * Retrieve the minimum value of a given column. * * @param \Illuminate\Contracts\Database\Query\Expression|string $column - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function min($column) { @@ -3576,7 +3578,7 @@ public function min($column) * Retrieve the maximum value of a given column. * * @param \Illuminate\Contracts\Database\Query\Expression|string $column - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function max($column) { @@ -3587,7 +3589,7 @@ public function max($column) * Retrieve the sum of the values of a given column. * * @param \Illuminate\Contracts\Database\Query\Expression|string $column - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function sum($column) { @@ -3600,7 +3602,7 @@ public function sum($column) * Retrieve the average of the values of a given column. * * @param \Illuminate\Contracts\Database\Query\Expression|string $column - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function avg($column) { @@ -3611,7 +3613,7 @@ public function avg($column) * Alias for the "avg" method. * * @param \Illuminate\Contracts\Database\Query\Expression|string $column - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function average($column) { @@ -3623,7 +3625,7 @@ public function average($column) * * @param string $function * @param array $columns - * @return mixed + * @return \Illuminate\Support\Collection|mixed */ public function aggregate($function, $columns = ['*']) { @@ -3632,6 +3634,10 @@ public function aggregate($function, $columns = ['*']) ->setAggregate($function, $columns) ->get($columns); + if ($this->groups) { + return $results; + } + if (! $results->isEmpty()) { return array_change_key_case((array) $results[0])['aggregate']; } diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index 1d3148f21150..1c82319fc1e9 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -138,7 +138,15 @@ protected function compileAggregate(Builder $query, $aggregate) $column = 'distinct '.$column; } - return 'select '.$aggregate['function'].'('.$column.') as aggregate'; + $sql = 'select '; + + if ($query->groups) { + $sql .= $this->columnize($query->groups).', '; + } + + $sql .= $aggregate['function'].'('.$column.') as aggregate'; + + return $sql; } /** @@ -1130,10 +1138,12 @@ protected function wrapUnion($sql) protected function compileUnionAggregate(Builder $query) { $sql = $this->compileAggregate($query, $query->aggregate); + $groups = $query->groups ? ' '.$this->compileGroups($query, $query->groups) : ''; $query->aggregate = null; + $query->groups = null; - return $sql.' from ('.$this->compileSelect($query).') as '.$this->wrapTable('temp_table'); + return $sql.' from ('.$this->compileSelect($query).') as '.$this->wrapTable('temp_table').$groups; } /** diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 096b82450d25..49a3eb40bfd3 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -25,6 +25,7 @@ use Illuminate\Pagination\Cursor; use Illuminate\Pagination\CursorPaginator; use Illuminate\Pagination\LengthAwarePaginator; +use Illuminate\Support\Collection; use Illuminate\Tests\Database\Fixtures\Enums\Bar; use InvalidArgumentException; use Mockery as m; @@ -1804,6 +1805,36 @@ public function testGroupBys() $this->assertEquals(['whereRawBinding', 'groupByRawBinding', 'havingRawBinding'], $builder->getBindings()); } + public function testGroupByAndAggregate() + { + $builder = $this->getBuilder(); + + $queryResults = [['aggregate' => 2, 'role' => 'admin', 'city' => 'NY'], ['aggregate' => 5, 'role' => 'user', 'city' => 'LA']]; + $builder->getConnection() + ->shouldReceive('select')->once() + ->with('select "role", "city", count(*) as aggregate from "users" group by "role", "city"', [], true) + ->andReturn($queryResults); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role', 'city')->aggregate('count'); + $this->assertEquals($queryResults, $results->toArray()); + } + + public function testGroupByUnionAndAggregate() + { + $builder = $this->getBuilder(); + + $queryResults = [['aggregate' => 2, 'role' => 'admin'], ['aggregate' => 5, 'role' => 'user']]; + $builder->getConnection() + ->shouldReceive('select')->once() + ->with('select "role", count(*) as aggregate from ((select * from "users") union (select * from "members")) as "temp_table" group by "role"', [], true) + ->andReturn($queryResults); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users') + ->union($this->getBuilder()->select('*')->from('members')) + ->groupBy('role')->aggregate('count'); + $this->assertEquals($queryResults, $results->toArray()); + } + public function testOrderBys() { $builder = $this->getBuilder(); @@ -3464,6 +3495,51 @@ public function testAggregateFunctions() $this->assertEquals(1, $results); } + public function testAggregateFunctionsWithGroupBy() + { + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", count(*) as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->count(); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", max("id") as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->max('id'); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", min("id") as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->min('id'); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", sum("id") as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->sum('id'); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", avg("id") as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->avg('id'); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + + $builder = $this->getBuilder(); + $builder->getConnection()->shouldReceive('select')->once()->with('select "role", avg("id") as aggregate from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]); + $builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results); + $results = $builder->from('users')->groupBy('role')->average('id'); + $this->assertInstanceOf(Collection::class, $results); + $this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray()); + } + public function testSqlServerExists() { $builder = $this->getSqlServerBuilder();