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

[10.x] Update SQL Server to FETCH and OFFSET for queries that do not include an order by #44937

Merged
merged 2 commits into from
Nov 15, 2022
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.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
126 changes: 31 additions & 95 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,25 @@ class SqlServerGrammar extends Grammar
'&', '&=', '|', '|=', '^', '^=',
];

/**
* The components that make up a select clause.
*
* @var string[]
*/
protected $selectComponents = [
'aggregate',
'columns',
'from',
'joins',
'wheres',
'groups',
'havings',
'orders',
'offset',
'limit',
'lock',
];

/**
* Compile a select query into SQL.
*
Expand All @@ -27,26 +46,12 @@ class SqlServerGrammar extends Grammar
*/
public function compileSelect(Builder $query)
{
if (! $query->offset) {
return parent::compileSelect($query);
}

if (is_null($query->columns)) {
$query->columns = ['*'];
// An ORDER BY clause is required for offset to work
if ($query->offset && empty($query->orders)) {
$query->orders[] = ['sql' => '(SELECT 0)'];
}

$components = $this->compileComponents($query);

if (! empty($components['orders'])) {
return parent::compileSelect($query)." offset {$query->offset} rows fetch next {$query->limit} rows only";
}

// If an offset is present on the query, we will need to wrap the query in
// a big "ANSI" offset syntax block. This is very nasty compared to the
// other database systems but is necessary for implementing features.
return $this->compileAnsiOffset(
$query, $components
);
return parent::compileSelect($query);
}

/**
Expand Down Expand Up @@ -235,69 +240,6 @@ protected function compileHavingBitwise($having)
return '('.$column.' '.$having['operator'].' '.$parameter.') != 0';
}

/**
* Create a full ANSI offset clause for the query.
*
* @param \Illuminate\Database\Query\Builder $query
* @param array $components
* @return string
*/
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']);

unset($components['orders']);

if ($this->queryOrderContainsSubquery($query)) {
$query->bindings = $this->sortBindingsForSubqueryOrderBy($query);
}

// Next we need to calculate the constraints that should be placed on the query
// to get the right offset and limit from our query but if there is no limit
// set we will just handle the offset only since that is all that matters.
$sql = $this->concatenate($components);

return $this->compileTableExpression($sql, $query);
}

/**
* Compile the over statement for a table expression.
*
* @param string $orderings
* @return string
*/
protected function compileOver($orderings)
{
return ", row_number() over ({$orderings}) as row_num";
}

/**
* Determine if the query's order by clauses contain a subquery.
*
* @param \Illuminate\Database\Query\Builder $query
* @return bool
*/
protected function queryOrderContainsSubquery($query)
{
if (! is_array($query->orders)) {
return false;
}

return Arr::first($query->orders, function ($value) {
return $this->isExpression($value['column'] ?? null);
}, false) !== false;
}

/**
* Move the order bindings to be after the "select" statement to account for an order by subquery.
*
Expand All @@ -311,20 +253,6 @@ protected function sortBindingsForSubqueryOrderBy($query)
});
}

/**
* Compile a common table expression for a query.
*
* @param string $sql
* @param \Illuminate\Database\Query\Builder $query
* @return string
*/
protected function compileTableExpression($sql, $query)
{
$constraint = $this->compileRowConstraint($query);

return "select * from ({$sql}) as temp_table where row_num {$constraint} order by row_num";
}

/**
* Compile the limit / offset row constraint for a query.
*
Expand Down Expand Up @@ -381,6 +309,10 @@ public function compileRandom($seed)
*/
protected function compileLimit(Builder $query, $limit)
{
if ($limit && $query->offset > 0) {
return "fetch next {$limit} rows only";
}

return '';
}

Expand All @@ -393,6 +325,10 @@ protected function compileLimit(Builder $query, $limit)
*/
protected function compileOffset(Builder $query, $offset)
{
if ($offset) {
return "offset {$offset} rows";
}

return '';
}

Expand Down
7 changes: 3 additions & 4 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -3502,19 +3502,18 @@ public function testSqlServerLimitsAndOffsets()
$this->assertSame('select top 10 * from [users]', $builder->toSql());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->skip(10);
$this->assertSame('select * from (select *, row_number() over (order by (select 0)) as row_num from [users]) as temp_table where row_num >= 11 order by row_num', $builder->toSql());
$builder->select('*')->from('users')->skip(10)->orderBy('email', 'desc');
$this->assertSame('select * from [users] order by [email] desc offset 10 rows', $builder->toSql());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->skip(10)->take(10);
$this->assertSame('select * from (select *, row_number() over (order by (select 0)) as row_num from [users]) as temp_table where row_num between 11 and 20 order by row_num', $builder->toSql());
$this->assertSame('select * from [users] order by (SELECT 0) offset 10 rows fetch next 10 rows only', $builder->toSql());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->skip(11)->take(10)->orderBy('email', 'desc');
$this->assertSame('select * from [users] order by [email] desc offset 11 rows fetch next 10 rows only', $builder->toSql());

$builder = $this->getSqlServerBuilder();
$subQueryBuilder = $this->getSqlServerBuilder();
$subQuery = function ($query) {
return $query->select('created_at')->from('logins')->where('users.name', 'nameBinding')->whereColumn('user_id', 'users.id')->limit(1);
};
Expand Down