diff --git a/src/Illuminate/Database/Eloquent/Relations/BelongsToMany.php b/src/Illuminate/Database/Eloquent/Relations/BelongsToMany.php index 955e008ece7c..9dbf0b6b6633 100755 --- a/src/Illuminate/Database/Eloquent/Relations/BelongsToMany.php +++ b/src/Illuminate/Database/Eloquent/Relations/BelongsToMany.php @@ -919,6 +919,34 @@ public function getRelationExistenceQueryForSelfJoin(Builder $query, Builder $pa return parent::getRelationExistenceQuery($query, $parentQuery, $columns); } + /** + * Alias to set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function take($value) + { + return $this->limit($value); + } + + /** + * Set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function limit($value) + { + if ($this->parent->exists) { + $this->query->limit($value); + } else { + $this->query->partitionLimit($value, $this->getQualifiedForeignPivotKeyName()); + } + + return $this; + } + /** * Get the key for comparing against the parent key in "has" query. * diff --git a/src/Illuminate/Database/Eloquent/Relations/HasManyThrough.php b/src/Illuminate/Database/Eloquent/Relations/HasManyThrough.php index 009b222e7359..f8a54c1bc812 100644 --- a/src/Illuminate/Database/Eloquent/Relations/HasManyThrough.php +++ b/src/Illuminate/Database/Eloquent/Relations/HasManyThrough.php @@ -514,6 +514,34 @@ public function getRelationExistenceQueryForSelfRelation(Builder $query, Builder ); } + /** + * Alias to set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function take($value) + { + return $this->limit($value); + } + + /** + * Set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function limit($value) + { + if ($this->farParent->exists) { + $this->query->limit($value); + } else { + $this->query->partitionLimit($value, $this->getQualifiedFirstKeyName()); + } + + return $this; + } + /** * Get a relationship join table hash. * diff --git a/src/Illuminate/Database/Eloquent/Relations/HasOneOrMany.php b/src/Illuminate/Database/Eloquent/Relations/HasOneOrMany.php index 20b2b4f7b76f..3330b8d505d0 100755 --- a/src/Illuminate/Database/Eloquent/Relations/HasOneOrMany.php +++ b/src/Illuminate/Database/Eloquent/Relations/HasOneOrMany.php @@ -359,6 +359,34 @@ public function getRelationExistenceQueryForSelfRelation(Builder $query, Builder ); } + /** + * Alias to set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function take($value) + { + return $this->limit($value); + } + + /** + * Set the "limit" value of the query. + * + * @param int $value + * @return $this + */ + public function limit($value) + { + if ($this->parent->exists) { + $this->query->limit($value); + } else { + $this->query->partitionLimit($value, $this->getQualifiedForeignKeyName()); + } + + return $this; + } + /** * Get a relationship join table hash. * diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 465366365c07..d5396ff10acb 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -131,6 +131,13 @@ class Builder */ public $limit; + /** + * The maximum number of records to return per partition. + * + * @var array + */ + public $partitionLimit; + /** * The number of records to skip. * @@ -1900,6 +1907,22 @@ protected function removeExistingOrdersFor($column) })->values()->all(); } + /** + * Add a "partition limit" clause to the query. + * + * @param int $value + * @param string $column + * @return $this + */ + public function partitionLimit($value, $column) + { + if ($value >= 0) { + $this->partitionLimit = compact('value', 'column'); + } + + return $this; + } + /** * Add a union statement to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index 273678395157..7534d2ea3b3f 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -46,6 +46,14 @@ class Grammar extends BaseGrammar */ public function compileSelect(Builder $query) { + if ($query->partitionLimit) { + if (is_null($query->columns)) { + $query->columns = ['*']; + } + + return $this->compilePartitionLimit($query); + } + // If the query does not have any columns set, we'll set the columns to the // * character to just get all of the columns from the database. Then we // can build the query and concatenate all the pieces together as one. @@ -693,6 +701,55 @@ protected function compileOffset(Builder $query, $offset) return 'offset '.(int) $offset; } + /** + * Compile a partition limit clause for the query. + * + * @param \Illuminate\Database\Query\Builder $query + * @return string + */ + protected function compilePartitionLimit(Builder $query) + { + $components = $this->compileComponents($query); + + $partition = 'partition by '.$this->wrap($query->partitionLimit['column']); + + $components['columns'] .= $this->compileOver($partition, $components['orders'] ?? ''); + + unset($components['orders']); + + $sql = $this->concatenate($components); + + $limit = (int) $query->partitionLimit['value']; + + return $this->compileTableExpression($sql, '<= '.$limit); + } + + /** + * Compile the over statement for a table expression. + * + * @param string $partition + * @param string $orderings + * @return string + */ + protected function compileOver($partition, $orderings) + { + $over = trim($partition.' '.$orderings); + + return ', row_number() over ('.$over.') as row_num'; + } + + /** + * Compile a common table expression for the query. + * + * @param string $sql + * @param string $constraint + * @return string + */ + protected function compileTableExpression($sql, $constraint) + { + return 'select * from ('.$sql.') as temp_table where row_num '.$constraint.' order by row_num'; + } + /** * Compile the "union" queries attached to the main query. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 5c3f66e6e602..5bd5f5febde0 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -2,7 +2,9 @@ namespace Illuminate\Database\Query\Grammars; +use PDO; use Illuminate\Support\Arr; +use Illuminate\Support\Str; use Illuminate\Database\Query\Builder; use Illuminate\Database\Query\JsonExpression; @@ -80,6 +82,60 @@ protected function compileJsonLength($column, $operator, $value) return 'json_length('.$field.$path.') '.$operator.' '.$value; } + /** + * Compile a partition limit clause for the query. + * + * @param \Illuminate\Database\Query\Builder $query + * @return string + */ + protected function compilePartitionLimit(Builder $query) + { + $version = $query->getConnection()->getPdo()->getAttribute(PDO::ATTR_SERVER_VERSION); + + if (version_compare($version, '8.0.11') >= 0) { + return parent::compilePartitionLimit($query); + } + + return $this->compileLegacyPartitionLimit($query); + } + + /** + * Compile a partition limit clause for the query on MySQL < 8.0. + * + * Derived from https://softonsofa.com/tweaking-eloquent-relations-how-to-get-n-related-models-per-parent/. + * + * @param \Illuminate\Database\Query\Builder $query + * @return string + */ + protected function compileLegacyPartitionLimit(Builder $query) + { + $column = Str::after($query->partitionLimit['column'], '.'); + + if ($query->joins && Str::contains(end($query->columns), ' as pivot_')) { + $column = 'pivot_'.$column; + } + + $column = $this->wrap($column); + + $partition = ', @row_num := if(@partition = '.$column.', @row_num + 1, 1) as row_num, @partition := '.$column; + + $orders = (array) $query->orders; + + array_unshift($orders, ['column' => $query->partitionLimit['column'], 'direction' => 'asc']); + + $query->orders = $orders; + + $components = $this->compileComponents($query); + + $sql = $this->concatenate($components); + + $from = '(select @row_num := 0, @partition := 0) as laravel_vars, ('.$sql.') as temp_table'; + + $limit = (int) $query->partitionLimit['value']; + + return 'select temp_table.*'.$partition.' from '.$from.' having row_num <= '.$limit.' order by row_num'; + } + /** * Compile a single union statement. * diff --git a/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php b/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php index 8c0f22ad3705..8d2bcaf80938 100755 --- a/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php @@ -2,6 +2,7 @@ namespace Illuminate\Database\Query\Grammars; +use PDO; use Illuminate\Support\Arr; use Illuminate\Support\Str; use Illuminate\Database\Query\Builder; @@ -55,6 +56,25 @@ public function compileSelect(Builder $query) return $sql; } + /** + * Compile a partition limit clause for the query. + * + * @param \Illuminate\Database\Query\Builder $query + * @return string + */ + protected function compilePartitionLimit(Builder $query) + { + $version = $query->getConnection()->getPdo()->getAttribute(PDO::ATTR_SERVER_VERSION); + + if (version_compare($version, '3.25.0') >= 0) { + return parent::compilePartitionLimit($query); + } + + $query->partitionLimit = null; + + return $this->compileSelect($query); + } + /** * Compile a single union statement. * diff --git a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php index bfe1000222fa..34be7ff999a2 100755 --- a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php @@ -166,17 +166,10 @@ protected function compileJsonLength($column, $operator, $value) */ protected function compileAnsiOffset(Builder $query, $components) { - // An ORDER BY clause is required to make this offset query work, so if one does - // not exist we'll just create a dummy clause to trick the database and so it - // does not complain about the queries for not having an "order by" clause. - if (empty($components['orders'])) { - $components['orders'] = 'order by (select 0)'; - } - // We need to add the row number to the query so we can compare it to the offset // and limit values given for the statements. So we will add an expression to // the "select" that will give back the row numbers on each of the records. - $components['columns'] .= $this->compileOver($components['orders']); + $components['columns'] .= $this->compileOver('', $components['orders'] ?? ''); unset($components['orders']); @@ -185,32 +178,28 @@ protected function compileAnsiOffset(Builder $query, $components) // set we will just handle the offset only since that is all that matters. $sql = $this->concatenate($components); - return $this->compileTableExpression($sql, $query); + $constraint = $this->compileRowConstraint($query); + + return $this->compileTableExpression($sql, $constraint); } /** * Compile the over statement for a table expression. * + * @param string $partition * @param string $orderings * @return string */ - protected function compileOver($orderings) - { - return ", row_number() over ({$orderings}) as row_num"; - } - - /** - * Compile a common table expression for a query. - * - * @param string $sql - * @param \Illuminate\Database\Query\Builder $query - * @return string - */ - protected function compileTableExpression($sql, $query) + protected function compileOver($partition, $orderings) { - $constraint = $this->compileRowConstraint($query); + // An ORDER BY clause is required to make this offset query work, so if one does + // not exist we'll just create a dummy clause to trick the database and so it + // does not complain about the queries for not having an "order by" clause. + if (empty($orderings)) { + $orderings = 'order by (select 0)'; + } - return "select * from ({$sql}) as temp_table where row_num {$constraint} order by row_num"; + return parent::compileOver($partition, $orderings); } /** diff --git a/tests/Database/DatabaseEloquentHasManyTest.php b/tests/Database/DatabaseEloquentHasManyTest.php index f2ce97b81dbd..aa2ec341b303 100755 --- a/tests/Database/DatabaseEloquentHasManyTest.php +++ b/tests/Database/DatabaseEloquentHasManyTest.php @@ -258,6 +258,18 @@ public function testCreateManyCreatesARelatedModelForEachRecord() $this->assertEquals($colin, $instances[1]); } + public function testLimit() + { + $relation = $this->getRelation(); + $relation->getQuery()->shouldReceive('partitionLimit')->once()->with(10, 'table.foreign_key'); + $relation->limit(10); + + $relation = $this->getRelation(); + $relation->getParent()->exists = true; + $relation->getQuery()->shouldReceive('limit')->once()->with(10); + $relation->limit(10); + } + protected function getRelation() { $builder = m::mock(Builder::class); diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 743c4b87d001..cd8702874692 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -2,6 +2,7 @@ namespace Illuminate\Tests\Database; +use PDO; use stdClass; use Mockery as m; use InvalidArgumentException; @@ -1028,6 +1029,86 @@ public function testForPage() $this->assertEquals('select * from "users" limit 0 offset 0', $builder->toSql()); } + public function testPartitionLimitMySql() + { + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('8.0.11'); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select * from (select *, row_number() over (partition by `user_id`) as row_num from `posts`) as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('8.0.11'); + $builder->select('id', 'user_id')->from('posts')->latest()->partitionLimit(10, 'user_id'); + $expected = 'select * from (select `id`, `user_id`, row_number() over (partition by `user_id` order by `created_at` desc) as row_num from `posts`) as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('5.7.9'); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select temp_table.*, @row_num := if(@partition = `user_id`, @row_num + 1, 1) as row_num, @partition := `user_id` from (select @row_num := 0, @partition := 0) as laravel_vars, (select * from `posts` order by `user_id` asc) as temp_table having row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('5.7.9'); + $builder->select('id', 'user_id')->from('posts')->latest()->partitionLimit(10, 'posts.user_id'); + $expected = 'select temp_table.*, @row_num := if(@partition = `user_id`, @row_num + 1, 1) as row_num, @partition := `user_id` from (select @row_num := 0, @partition := 0) as laravel_vars, (select `id`, `user_id` from `posts` order by `posts`.`user_id` asc, `created_at` desc) as temp_table having row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('5.7.9'); + $builder->select('roles.*, role_user.user_id as pivot_user_id')->from('posts')->join('role_user', 'roles.id', '=', 'role_user.role_id')->latest()->partitionLimit(10, 'role_user.user_id'); + $expected = 'select temp_table.*, @row_num := if(@partition = `pivot_user_id`, @row_num + 1, 1) as row_num, @partition := `pivot_user_id` from (select @row_num := 0, @partition := 0) as laravel_vars, (select `roles`.`*, role_user`.`user_id` as `pivot_user_id` from `posts` inner join `role_user` on `roles`.`id` = `role_user`.`role_id` order by `role_user`.`user_id` asc, `created_at` desc) as temp_table having row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + } + + public function testPartitionLimitPostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select * from (select *, row_number() over (partition by "user_id") as row_num from "posts") as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getPostgresBuilder(); + $builder->select('id', 'user_id')->from('posts')->latest()->partitionLimit(10, 'user_id'); + $expected = 'select * from (select "id", "user_id", row_number() over (partition by "user_id" order by "created_at" desc) as row_num from "posts") as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + } + + public function testPartitionLimitSqlite() + { + $builder = $this->getSQLiteBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('3.25.0'); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select * from (select *, row_number() over (partition by "user_id") as row_num from "posts") as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getSQLiteBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('3.25.0'); + $builder->select('id', 'user_id')->from('posts')->latest()->partitionLimit(10, 'user_id'); + $expected = 'select * from (select "id", "user_id", row_number() over (partition by "user_id" order by "created_at" desc) as row_num from "posts") as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getSQLiteBuilder(); + $builder->getConnection()->shouldReceive('getPdo->getAttribute')->with(PDO::ATTR_SERVER_VERSION)->andReturn('3.24.0'); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select * from "posts"'; + $this->assertEquals($expected, $builder->toSql()); + } + + public function testPartitionLimitSqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('posts')->partitionLimit(10, 'user_id'); + $expected = 'select * from (select *, row_number() over (partition by [user_id] order by (select 0)) as row_num from [posts]) as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('id', 'user_id')->from('posts')->latest()->partitionLimit(10, 'user_id'); + $expected = 'select * from (select [id], [user_id], row_number() over (partition by [user_id] order by [created_at] desc) as row_num from [posts]) as temp_table where row_num <= 10 order by row_num'; + $this->assertEquals($expected, $builder->toSql()); + } + public function testGetCountForPaginationWithBindings() { $builder = $this->getBuilder();