Skip to content

Commit

Permalink
[11.x] Support DB aggregate by group (#53209)
Browse files Browse the repository at this point in the history
* Support aggregation by group

* Support group aggregate with union

* Change return type of all aggregate functions

* Fix CS

* formatting

---------

Co-authored-by: Taylor Otwell <[email protected]>
  • Loading branch information
GromNaN and taylorotwell authored Nov 18, 2024
1 parent 306c065 commit 6a491c2
Show file tree
Hide file tree
Showing 3 changed files with 102 additions and 10 deletions.
22 changes: 14 additions & 8 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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)
{
Expand All @@ -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)
{
Expand All @@ -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)
{
Expand All @@ -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)
{
Expand All @@ -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)
{
Expand All @@ -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 = ['*'])
{
Expand All @@ -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'];
}
Expand Down
14 changes: 12 additions & 2 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;
}

/**
Expand Down Expand Up @@ -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;
}

/**
Expand Down
76 changes: 76 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down Expand Up @@ -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();
Expand Down Expand Up @@ -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();
Expand Down

0 comments on commit 6a491c2

Please sign in to comment.