Skip to content

Commit

Permalink
[8.x] Add proper paging offset when possible to sql server (#39863)
Browse files Browse the repository at this point in the history
* Add proper paging offset when possible to sql server

* update styling

* formatting

Co-authored-by: Taylor Otwell <taylor@laravel.com>
  • Loading branch information
joelharkes and taylorotwell committed Dec 2, 2021
1 parent 0b0d3c5 commit beea2aa
Show file tree
Hide file tree
Showing 2 changed files with 15 additions and 9 deletions.
14 changes: 10 additions & 4 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Expand Up @@ -31,15 +31,21 @@ public function compileSelect(Builder $query)
return parent::compileSelect($query);
}

// 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.
if (is_null($query->columns)) {
$query->columns = ['*'];
}

$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, $this->compileComponents($query)
$query, $components
);
}

Expand Down
10 changes: 5 additions & 5 deletions tests/Database/DatabaseQueryBuilderTest.php
Expand Up @@ -1221,7 +1221,7 @@ public function testOrderBysSqlServer()

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->skip(25)->take(10)->orderByRaw('[email] desc');
$this->assertSame('select * from (select *, row_number() over (order by [email] desc) as row_num from [users]) as temp_table where row_num between 26 and 35 order by row_num', $builder->toSql());
$this->assertSame('select * from [users] order by [email] desc offset 25 rows fetch next 10 rows only', $builder->toSql());
}

public function testReorder()
Expand Down Expand Up @@ -3109,17 +3109,17 @@ public function testSqlServerLimitsAndOffsets()
$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());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->skip(10)->take(10)->orderBy('email', 'desc');
$this->assertSame('select * from (select *, row_number() over (order by [email] desc) as row_num from [users]) as temp_table where row_num between 11 and 20 order by row_num', $builder->toSql());
$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);
};
$builder->select('*')->from('users')->where('email', 'emailBinding')->orderBy($subQuery)->skip(10)->take(10);
$this->assertSame('select * from (select *, row_number() over (order by (select top 1 [created_at] from [logins] where [users].[name] = ? and [user_id] = [users].[id]) asc) as row_num from [users] where [email] = ?) as temp_table where row_num between 11 and 20 order by row_num', $builder->toSql());
$this->assertEquals(['nameBinding', 'emailBinding'], $builder->getBindings());
$this->assertSame('select * from [users] where [email] = ? order by (select top 1 [created_at] from [logins] where [users].[name] = ? and [user_id] = [users].[id]) asc offset 10 rows fetch next 10 rows only', $builder->toSql());
$this->assertEquals(['emailBinding', 'nameBinding'], $builder->getBindings());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->take('foo');
Expand Down

0 comments on commit beea2aa

Please sign in to comment.