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

Fix wrong offset in SQL Server when not using ORDER BY #1318

Closed
wants to merge 5 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 6 additions & 6 deletions framework/db/schema/mssql/CMssqlCommandBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -190,22 +190,22 @@ public function applyLimit($sql, $limit, $offset)

/**
* Rewrite sql to apply $limit > and $offset > 0 for MSSQL database.
* See http://troels.arvin.dk/db/rdbms/#select-limit-offset
* @param string $sql sql query
* @param integer $limit $limit > 0
* @param integer $offset $offset > 0
* @return string modified sql query applied with limit and offset.
*
* @author Wei Zhuo <weizhuo[at]gmail[dot]com>
* @author Diego Rocha <diego[dot]rocha[dot]br[at]gmail[dot]com>
*/
protected function rewriteLimitOffsetSql($sql, $limit, $offset)
{
$fetch = $limit+$offset;
$sql = preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',"\\1SELECT\\2 TOP $fetch", $sql);
$end = $limit + $offset;
$start = $end - $limit + 1;
$ordering = $this->findOrdering($sql);
$orginalOrdering = $this->joinOrdering($ordering, '[__outer__]');
$reverseOrdering = $this->joinOrdering($this->reverseDirection($ordering), '[__inner__]');
$sql = "SELECT * FROM (SELECT TOP {$limit} * FROM ($sql) as [__inner__] {$reverseOrdering}) as [__outer__] {$orginalOrdering}";
$rowNumberOrdering = !empty($orginalOrdering) ? $orginalOrdering : 'ORDER BY (SELECT 1)';
$sqlWithoutOrder = preg_replace('/([ ]ORDER BY)[\s"\[](.*)(ASC|DESC)?(?:[\s"\[]|$|COMPUTE|FOR)/i','',$sql);
$sql = "SELECT * FROM (SELECT ROW_NUMBER() OVER({$rowNumberOrdering}) AS [__RowNumber__], * FROM ({$sqlWithoutOrder}) as [__inner__]) as [__outer__] WHERE [__RowNumber__] BETWEEN {$start} AND {$end}";
return $sql;
}

Expand Down
3 changes: 2 additions & 1 deletion tests/framework/db/schema/CMssqlTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -212,7 +212,8 @@ public function testCommandBuilder()
'order'=>'title',
'limit'=>2,
'offset'=>3)));
$this->assertEquals('SELECT * FROM (SELECT TOP 2 * FROM (SELECT TOP 5 id, title FROM [dbo].[posts] [t] ORDER BY title) as [__inner__] ORDER BY title DESC) as [__outer__] ORDER BY title ASC',$c->text);
$expectedSql = 'SELECT * FROM (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT 1)) AS [__RowNumber__], * FROM (SELECT id, title FROM [dbo].[posts] [t]) as [__inner__]) as [__outer__] WHERE [__RowNumber__] BETWEEN 4 AND 5 ORDER BY title ASC';
$this->assertEquals($expectedSql,$c->text);
$rows=$c->query()->readAll();
$this->assertEquals(2,count($rows));
$this->assertEquals('post 4',$rows[0]['title']);
Expand Down