Skip to content

Commit 4b9aeae

Browse files
[11.x] Support DB aggregate by group (new methods) (#53679)
* Support aggregation by group * Move group columns after aggregate result for safe backward compatibility * formatting * formatting --------- Co-authored-by: Taylor Otwell <[email protected]>
1 parent 7a80e6c commit 4b9aeae

File tree

3 files changed

+153
-2
lines changed

3 files changed

+153
-2
lines changed

src/Illuminate/Database/Query/Builder.php

Lines changed: 70 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3561,6 +3561,17 @@ public function count($columns = '*')
35613561
return (int) $this->aggregate(__FUNCTION__, Arr::wrap($columns));
35623562
}
35633563

3564+
/**
3565+
* Retrieve the "count" of the distinct results of a given column for each group.
3566+
*
3567+
* @param \Illuminate\Contracts\Database\Query\Expression|string $columns
3568+
* @return \Illuminate\Support\Collection
3569+
*/
3570+
public function countByGroup($columns = '*')
3571+
{
3572+
return $this->aggregateByGroup('count', Arr::wrap($columns));
3573+
}
3574+
35643575
/**
35653576
* Retrieve the minimum value of a given column.
35663577
*
@@ -3572,6 +3583,17 @@ public function min($column)
35723583
return $this->aggregate(__FUNCTION__, [$column]);
35733584
}
35743585

3586+
/**
3587+
* Retrieve the minimum value of a given column by group.
3588+
*
3589+
* @param \Illuminate\Contracts\Database\Query\Expression|string $column
3590+
* @return \Illuminate\Support\Collection
3591+
*/
3592+
public function minByGroup($column)
3593+
{
3594+
return $this->aggregateByGroup('min', [$column]);
3595+
}
3596+
35753597
/**
35763598
* Retrieve the maximum value of a given column.
35773599
*
@@ -3583,6 +3605,17 @@ public function max($column)
35833605
return $this->aggregate(__FUNCTION__, [$column]);
35843606
}
35853607

3608+
/**
3609+
* Retrieve the maximum value of a given column by group.
3610+
*
3611+
* @param \Illuminate\Contracts\Database\Query\Expression|string $column
3612+
* @return \Illuminate\Support\Collection
3613+
*/
3614+
public function maxByGroup($column)
3615+
{
3616+
return $this->aggregateByGroup('max', [$column]);
3617+
}
3618+
35863619
/**
35873620
* Retrieve the sum of the values of a given column.
35883621
*
@@ -3596,6 +3629,17 @@ public function sum($column)
35963629
return $result ?: 0;
35973630
}
35983631

3632+
/**
3633+
* Retrieve the sum of the values of a given column by group.
3634+
*
3635+
* @param \Illuminate\Contracts\Database\Query\Expression|string $column
3636+
* @return \Illuminate\Support\Collection
3637+
*/
3638+
public function sumByGroup($column)
3639+
{
3640+
return $this->aggregateByGroup('sum', [$column]);
3641+
}
3642+
35993643
/**
36003644
* Retrieve the average of the values of a given column.
36013645
*
@@ -3607,6 +3651,17 @@ public function avg($column)
36073651
return $this->aggregate(__FUNCTION__, [$column]);
36083652
}
36093653

3654+
/**
3655+
* Retrieve the average of the values of a given column by group.
3656+
*
3657+
* @param \Illuminate\Contracts\Database\Query\Expression|string $column
3658+
* @return \Illuminate\Support\Collection
3659+
*/
3660+
public function avgByGroup($column)
3661+
{
3662+
return $this->aggregateByGroup('avg', [$column]);
3663+
}
3664+
36103665
/**
36113666
* Alias for the "avg" method.
36123667
*
@@ -3637,6 +3692,21 @@ public function aggregate($function, $columns = ['*'])
36373692
}
36383693
}
36393694

3695+
/**
3696+
* Execute an aggregate function for each group.
3697+
*
3698+
* @param string $function
3699+
* @param array $columns
3700+
* @return \Illuminate\Support\Collection
3701+
*/
3702+
public function aggregateByGroup(string $function, array $columns = ['*'])
3703+
{
3704+
return $this->cloneWithout($this->unions || $this->havings ? [] : ['columns'])
3705+
->cloneWithoutBindings($this->unions || $this->havings ? [] : ['select'])
3706+
->setAggregate($function, $columns)
3707+
->get($columns);
3708+
}
3709+
36403710
/**
36413711
* Execute a numeric aggregate function on the database.
36423712
*

src/Illuminate/Database/Query/Grammars/Grammar.php

Lines changed: 12 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -139,7 +139,15 @@ protected function compileAggregate(Builder $query, $aggregate)
139139
$column = 'distinct '.$column;
140140
}
141141

142-
return 'select '.$aggregate['function'].'('.$column.') as aggregate';
142+
$sql = 'select ';
143+
144+
$sql .= $aggregate['function'].'('.$column.') as aggregate';
145+
146+
if ($query->groups) {
147+
$sql .= ', '.$this->columnize($query->groups);
148+
}
149+
150+
return $sql;
143151
}
144152

145153
/**
@@ -1131,10 +1139,12 @@ protected function wrapUnion($sql)
11311139
protected function compileUnionAggregate(Builder $query)
11321140
{
11331141
$sql = $this->compileAggregate($query, $query->aggregate);
1142+
$groups = $query->groups ? ' '.$this->compileGroups($query, $query->groups) : '';
11341143

11351144
$query->aggregate = null;
1145+
$query->groups = null;
11361146

1137-
return $sql.' from ('.$this->compileSelect($query).') as '.$this->wrapTable('temp_table');
1147+
return $sql.' from ('.$this->compileSelect($query).') as '.$this->wrapTable('temp_table').$groups;
11381148
}
11391149

11401150
/**

tests/Database/DatabaseQueryBuilderTest.php

Lines changed: 71 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -25,6 +25,7 @@
2525
use Illuminate\Pagination\Cursor;
2626
use Illuminate\Pagination\CursorPaginator;
2727
use Illuminate\Pagination\LengthAwarePaginator;
28+
use Illuminate\Support\Collection;
2829
use Illuminate\Tests\Database\Fixtures\Enums\Bar;
2930
use InvalidArgumentException;
3031
use Mockery as m;
@@ -1804,6 +1805,38 @@ public function testGroupBys()
18041805
$this->assertEquals(['whereRawBinding', 'groupByRawBinding', 'havingRawBinding'], $builder->getBindings());
18051806
}
18061807

1808+
public function testAggregateByGroup()
1809+
{
1810+
$builder = $this->getBuilder();
1811+
1812+
$queryResults = [['aggregate' => 2, 'role' => 'admin', 'city' => 'NY'], ['aggregate' => 5, 'role' => 'user', 'city' => 'LA']];
1813+
$builder->getConnection()
1814+
->shouldReceive('select')->once()
1815+
->with('select count(*) as aggregate, "role", "city" from "users" group by "role", "city"', [], true)
1816+
->andReturn($queryResults);
1817+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
1818+
$builder->from('users')->groupBy('role', 'city');
1819+
$builder->aggregate = ['function' => 'count', 'columns' => ['*']];
1820+
$results = $builder->get();
1821+
$this->assertEquals($queryResults, $results->toArray());
1822+
}
1823+
1824+
public function testUnionAndAggregateByGroup()
1825+
{
1826+
$builder = $this->getBuilder();
1827+
1828+
$queryResults = [['aggregate' => 2, 'role' => 'admin'], ['aggregate' => 5, 'role' => 'user']];
1829+
$builder->getConnection()
1830+
->shouldReceive('select')->once()
1831+
->with('select count(*) as aggregate, "role" from ((select * from "users") union (select * from "members")) as "temp_table" group by "role"', [], true)
1832+
->andReturn($queryResults);
1833+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
1834+
$results = $builder->from('users')
1835+
->union($this->getBuilder()->select('*')->from('members'))
1836+
->groupBy('role')->aggregateByGroup('count');
1837+
$this->assertEquals($queryResults, $results->toArray());
1838+
}
1839+
18071840
public function testOrderBys()
18081841
{
18091842
$builder = $this->getBuilder();
@@ -3464,6 +3497,44 @@ public function testAggregateFunctions()
34643497
$this->assertEquals(1, $results);
34653498
}
34663499

3500+
public function testAggregateFunctionsWithGroupBy()
3501+
{
3502+
$builder = $this->getBuilder();
3503+
$builder->getConnection()->shouldReceive('select')->once()->with('select count(*) as aggregate, "role" from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]);
3504+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
3505+
$results = $builder->from('users')->groupBy('role')->countByGroup();
3506+
$this->assertInstanceOf(Collection::class, $results);
3507+
$this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray());
3508+
3509+
$builder = $this->getBuilder();
3510+
$builder->getConnection()->shouldReceive('select')->once()->with('select max("id") as aggregate, "role" from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]);
3511+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
3512+
$results = $builder->from('users')->groupBy('role')->maxByGroup('id');
3513+
$this->assertInstanceOf(Collection::class, $results);
3514+
$this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray());
3515+
3516+
$builder = $this->getBuilder();
3517+
$builder->getConnection()->shouldReceive('select')->once()->with('select min("id") as aggregate, "role" from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]);
3518+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
3519+
$results = $builder->from('users')->groupBy('role')->minByGroup('id');
3520+
$this->assertInstanceOf(Collection::class, $results);
3521+
$this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray());
3522+
3523+
$builder = $this->getBuilder();
3524+
$builder->getConnection()->shouldReceive('select')->once()->with('select sum("id") as aggregate, "role" from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]);
3525+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
3526+
$results = $builder->from('users')->groupBy('role')->sumByGroup('id');
3527+
$this->assertInstanceOf(Collection::class, $results);
3528+
$this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray());
3529+
3530+
$builder = $this->getBuilder();
3531+
$builder->getConnection()->shouldReceive('select')->once()->with('select avg("id") as aggregate, "role" from "users" group by "role"', [], true)->andReturn([['role' => 'admin', 'aggregate' => 1]]);
3532+
$builder->getProcessor()->shouldReceive('processSelect')->once()->andReturnUsing(fn ($builder, $results) => $results);
3533+
$results = $builder->from('users')->groupBy('role')->avgByGroup('id');
3534+
$this->assertInstanceOf(Collection::class, $results);
3535+
$this->assertEquals([['role' => 'admin', 'aggregate' => 1]], $results->toArray());
3536+
}
3537+
34673538
public function testSqlServerExists()
34683539
{
34693540
$builder = $this->getSqlServerBuilder();

0 commit comments

Comments
 (0)