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

[11.x] Support DB aggregate by group #53209

Merged
merged 5 commits into from
Nov 18, 2024
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.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
22 changes: 14 additions & 8 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -3553,18 +3553,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 @@ -3575,7 +3577,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 @@ -3586,7 +3588,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 @@ -3599,7 +3601,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 @@ -3610,7 +3612,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 @@ -3622,7 +3624,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 @@ -3631,6 +3633,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 @@ -3151,6 +3182,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