diff --git a/src/Illuminate/Database/Eloquent/Concerns/QueriesRelationships.php b/src/Illuminate/Database/Eloquent/Concerns/QueriesRelationships.php index 5f2ec2dab7b9..6d261d6f4259 100644 --- a/src/Illuminate/Database/Eloquent/Concerns/QueriesRelationships.php +++ b/src/Illuminate/Database/Eloquent/Concerns/QueriesRelationships.php @@ -176,6 +176,69 @@ public function orWhereDoesntHave($relation, Closure $callback = null) * @return $this */ public function withCount($relations) + { + $relations = is_array($relations) ? $relations : func_get_args(); + + return $this->withAggregate($relations, 'count', '*'); + } + + /** + * Add subselect queries to sum the relations. + * + * @param mixed $relations + * @param string $column + * @return $this + */ + public function withSum($relations, $column) + { + return $this->withAggregate($relations, 'sum', $column); + } + + /** + * Add subselect queries to avg the relations. + * + * @param mixed $relations + * @param string $column + * @return $this + */ + public function withAvg($relations, $column) + { + return $this->withAggregate($relations, 'avg', $column); + } + + /** + * Add subselect queries to max the relations. + * + * @param mixed $relations + * @param string $column + * @return $this + */ + public function withMax($relations, $column) + { + return $this->withAggregate($relations, 'max', $column); + } + + /** + * Add subselect queries to min the relations. + * + * @param mixed $relations + * @param string $column + * @return $this + */ + public function withMin($relations, $column) + { + return $this->withAggregate($relations, 'min', $column); + } + + /** + * Add subselect queries to aggregate the relations. + * + * @param mixed $relations + * @param string $aggregate + * @param string $column + * @return $this + */ + public function withAggregate($relations, $aggregate, $column) { if (empty($relations)) { return $this; @@ -185,7 +248,7 @@ public function withCount($relations) $this->query->select([$this->query->from.'.*']); } - $relations = is_array($relations) ? $relations : func_get_args(); + $relations = is_array($relations) ? $relations : [$relations]; foreach ($this->parseWithRelations($relations) as $name => $constraints) { // First we will determine if the name has been aliased using an "as" clause on the name @@ -204,8 +267,8 @@ public function withCount($relations) // Here we will get the relationship count query and prepare to add it to the main query // as a sub-select. First, we'll get the "has" query and use that to get the relation // count query. We will normalize the relation name then append _count as the name. - $query = $relation->getRelationExistenceCountQuery( - $relation->getRelated()->newQuery(), $this + $query = $relation->getRelationExistenceAggregatesQuery( + $relation->getRelated()->newQuery(), $this, $aggregate, $column ); $query->callScope($constraints); @@ -219,9 +282,9 @@ public function withCount($relations) // Finally we will add the proper result column alias to the query and run the subselect // statement against the query builder. Then we will return the builder instance back // to the developer for further constraint chaining that needs to take place on it. - $column = $alias ?? Str::snake($name.'_count'); + $column_alias = $alias ?? Str::snake($name.'_'.strtolower($aggregate)); - $this->selectSub($query, $column); + $this->selectSub($query, $column_alias); } return $this; diff --git a/src/Illuminate/Database/Eloquent/Relations/Relation.php b/src/Illuminate/Database/Eloquent/Relations/Relation.php index ae6ddbf4a5b2..d777f72f638b 100755 --- a/src/Illuminate/Database/Eloquent/Relations/Relation.php +++ b/src/Illuminate/Database/Eloquent/Relations/Relation.php @@ -195,6 +195,22 @@ public function getRelationExistenceCountQuery(Builder $query, Builder $parentQu )->setBindings([], 'select'); } + /** + * Add the constraints for a relationship sum query. + * + * @param \Illuminate\Database\Eloquent\Builder $query + * @param \Illuminate\Database\Eloquent\Builder $parentQuery + * @param string $aggregate + * @param string $column + * @return \Illuminate\Database\Eloquent\Builder + */ + public function getRelationExistenceAggregatesQuery(Builder $query, Builder $parentQuery, $aggregate, $column) + { + return $this->getRelationExistenceQuery( + $query, $parentQuery, new Expression($aggregate."({$column})") + )->setBindings([], 'select'); + } + /** * Add the constraints for an internal relationship existence query. * @@ -202,7 +218,7 @@ public function getRelationExistenceCountQuery(Builder $query, Builder $parentQu * * @param \Illuminate\Database\Eloquent\Builder $query * @param \Illuminate\Database\Eloquent\Builder $parentQuery - * @param array|mixed $columns + * @param array|mixed $columns * @return \Illuminate\Database\Eloquent\Builder */ public function getRelationExistenceQuery(Builder $query, Builder $parentQuery, $columns = ['*']) diff --git a/tests/Integration/Database/EloquentWithAggregateTest.php b/tests/Integration/Database/EloquentWithAggregateTest.php new file mode 100644 index 000000000000..40f94f7dd551 --- /dev/null +++ b/tests/Integration/Database/EloquentWithAggregateTest.php @@ -0,0 +1,106 @@ +increments('id'); + $table->string('reference'); + $table->timestamps(); + }); + + Schema::create('product_orders', function ($table) { + $table->increments('id'); + $table->string('name'); + $table->integer('order_id')->unsigned(); + $table->integer('qty'); + $table->integer('price'); + }); + + DB::table('orders')->insert([ + 'reference' => '12345678', + ]); + + // products in orders + DB::table('product_orders')->insert([ + ['name' =>'imac', 'qty'=>'1', 'price'=>'1500', 'order_id'=>1], + ['name' =>'galaxy s9', 'qty'=>'2', 'price'=>'1000', 'order_id'=>1], + ['name' =>'apple watch', 'qty'=>'3', 'price'=>'1200', 'order_id'=>1], + ]); + } + + public function testWithCount() + { + $actual = Orders::withAggregate('products', 'count', '*')->first(); + $expected = DB::select(DB::raw('select (select count(*) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "products_count" from "orders"'))[0]; + $this->assertEquals($expected->products_count, $actual->products_count); + } + + public function testWithSum() + { + $actual = Orders::withSum('products', 'qty')->first(); + $expected = DB::select(DB::raw('select (select sum(qty) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "products_sum" from "orders"'))[0]; // sum of qty products in order + $this->assertEquals($expected->products_sum, $actual->products_sum); + } + + public function testWithAvg() + { + $actual = Orders::withAvg('products', 'price')->first(); + $expected = DB::select(DB::raw('select (select avg(price) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "products_avg" from "orders"'))[0]; // sum of qty products in order + $this->assertEquals($expected->products_avg, $actual->products_avg); + } + + public function testWithMinAndAlias() + { + $actual = Orders::withMin('products as min_price', 'price')->first(); + $expected = DB::select(DB::raw('select (select min(price) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "min_price" from "orders"'))[0]; // sum of qty products in order + $this->assertEquals($expected->min_price, $actual->min_price); + } + + public function testWithMaxWithAliasWithWhere() + { + $actual = Orders::withMax(['products as higher_price'=>function ($query) { + $query->where('qty', '>', 1); + }], 'price')->first(); + $expected = DB::select(DB::raw('select (select max(price) from "product_orders" where "orders"."id" = "product_orders"."order_id" and "qty" > 1) as "higher_price" from "orders"'))[0]; + $this->assertEquals($expected->higher_price, $actual->higher_price); + } + + public function testWithSumPricesAndCountQtyWithAliases() + { + $actual = Orders::withSum('products as order_price', 'price')->withSum('products as order_products_count', 'qty')->withCount('products')->first(); + $expected = DB::select(DB::raw('select (select sum(price) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "order_price", (select sum(qty) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "order_products_count", (select count(*) from "product_orders" where "orders"."id" = "product_orders"."order_id") as "products_count" from "orders"'))[0]; + $this->assertEquals($expected->order_price, $actual->order_price); + $this->assertEquals($expected->products_count, $actual->products_count); + $this->assertEquals($expected->order_products_count, $actual->order_products_count); + } +} + +class Orders extends Model +{ + protected $fillable = [ + 'reference', + ]; + + public function products() + { + return $this->hasMany(ProductOrders::class, 'order_id'); + } +} + +class ProductOrders extends Model +{ + protected $table = 'product_orders'; + protected $fillable = [ + 'name', 'qty', 'price', + ]; +}