diff --git a/framework/db/schema/mssql/CMssqlCommandBuilder.php b/framework/db/schema/mssql/CMssqlCommandBuilder.php index b5ddfe543..4b2263d96 100644 --- a/framework/db/schema/mssql/CMssqlCommandBuilder.php +++ b/framework/db/schema/mssql/CMssqlCommandBuilder.php @@ -149,6 +149,32 @@ class CMssqlCommandBuilder extends CDbCommandBuilder } /** + * Apply limit and offset to sql query + * @param string $sql SQL query string. + * @param integer $limit maximum number of rows, -1 to ignore limit. + * @param integer $offset row offset, -1 to ignore offset. + * @return string SQL with limit and offset. + * @see https://github.com/yiisoft/yii/issues/4491 + */ + public function applyLimit($sql, $limit, $offset) + { + $limit = $limit!==null ? (int)$limit : -1; + $offset = $offset!==null ? (int)$offset : -1; + + if($limit <= 0 && $offset <=0) // no limit, no offset + return $sql; + if($limit > 0 && $offset <= 0) // only limit + return preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',"\\1SELECT\\2 TOP $limit", $sql); + + if(version_compare($this->dbConnection->getServerVersion(), '11', '<')) + return $this->oldRewriteLimitOffsetSql($sql, $limit, $offset); + else + return $this->newRewriteLimitOffsetSql($sql, $limit, $offset); + } + + /** + * Rewrite sql to apply $limit and $offset for MSSQL database version 10 (2008) and lower. + * * This is a port from Prado Framework. * * Overrides parent implementation. Alters the sql to apply $limit and $offset. @@ -185,50 +211,18 @@ class CMssqlCommandBuilder extends CDbCommandBuilder * * * - * @param string $sql SQL query string. - * @param integer $limit maximum number of rows, -1 to ignore limit. - * @param integer $offset row offset, -1 to ignore offset. - * @return string SQL with limit and offset. - * - * @author Wei Zhuo - */ - public function applyLimit($sql, $limit, $offset) - { - $limit = $limit!==null ? (int)$limit : -1; - $offset = $offset!==null ? (int)$offset : -1; - if ($limit > 0 && $offset <= 0) //just limit - $sql = preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',"\\1SELECT\\2 TOP $limit", $sql); - elseif($limit > 0 && $offset > 0) - $sql = $this->rewriteLimitOffsetSql($sql, $limit,$offset); - return $sql; - } - - /** * @param string $sql sql query - * @param integer $limit $limit > 0 - * @param integer $offset $offset > 0 + * @param integer $limit $limit + * @param integer $offset $offset * @return string modified sql query applied with limit and offset. - */ - protected function rewriteLimitOffsetSql($sql, $limit, $offset) - { - if(version_compare($this->dbConnection->getServerVersion(), '11', '<')) - return $this->oldRewriteLimitOffsetSql($sql, $limit, $offset); - else - return $this->newRewriteLimitOffsetSql($sql, $limit, $offset); - } - - /** - * Rewrite sql to apply $limit > and $offset > 0 for MSSQL database version 10 (2008) and lower. - * See https://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 + * @see https://troels.arvin.dk/db/rdbms/#select-limit-offset + * @see https://github.com/yiisoft/yii/issues/4491 */ protected function oldRewriteLimitOffsetSql($sql, $limit, $offset) { + if ($limit <= 0) // Offset without limit has never worked for MSSQL 10 and older, see https://github.com/yiisoft/yii/pull/4501 + return $sql; + $fetch = $limit+$offset; $sql = preg_replace('/^([\s(])*SELECT( DISTINCT)?(?!\s*TOP\s*\()/i',"\\1SELECT\\2 TOP $fetch", $sql); $ordering = $this->findOrdering($sql); @@ -243,17 +237,21 @@ class CMssqlCommandBuilder extends CDbCommandBuilder * @see https://learn.microsoft.com/en-us/sql/t-sql/queries/select-order-by-clause-transact-sql?view=sql-server-ver15#using-offset-and-fetch-to-limit-the-rows-returned * @see https://github.com/yiisoft/yii/issues/4491 * @param string $sql sql query - * @param integer $limit $limit > 0 - * @param integer $offset $offset > 0 + * @param integer $limit $limit + * @param integer $offset $offset * @return string modified sql query applied w th limit and offset. */ protected function newRewriteLimitOffsetSql($sql, $limit, $offset) { - $order = $this->findOrdering($sql); - if(empty($order)) + // ORDER BY is required when using OFFSET and FETCH + if(empty($this->findOrdering($sql))) $sql .= " ORDER BY (SELECT NULL)"; - $sql .= sprintf(" OFFSET %d ROWS FETCH NEXT %d ROWS ONLY", $offset, $limit); + $sql .= sprintf(" OFFSET %d ROWS", $offset); + + if($limit > 0) + $sql .= sprintf(' FETCH NEXT %d ROWS ONLY', $limit); + return $sql; } diff --git a/tests/framework/db/schema/CMssqlCommandBuilderTest.php b/tests/framework/db/schema/CMssqlCommandBuilderTest.php index 9b782e437..02a5cf876 100644 --- a/tests/framework/db/schema/CMssqlCommandBuilderTest.php +++ b/tests/framework/db/schema/CMssqlCommandBuilderTest.php @@ -36,10 +36,18 @@ class CMssqlCommandBuilderTest extends CTestCase $this->db->method('getSchema')->willReturn($schema); } + /** + * Verify generated SQL for MSSQL 10 (2008) and older hasn't changed + */ public function testCommandBuilderOldMssql() { $this->db->method('getServerVersion')->willReturn('10'); + $command = $this->createFindCommand([ + 'limit'=>3, + ]); + $this->assertEquals('SELECT TOP 3 * FROM [dbo].[posts] [t]', $command->text); + $command = $this->createFindCommand([ 'select'=>'id, title', 'order'=>'title', @@ -53,25 +61,52 @@ class CMssqlCommandBuilderTest extends CTestCase 'offset'=>3 ]); $this->assertEquals('SELECT * FROM (SELECT TOP 2 * FROM (SELECT TOP 5 * FROM [dbo].[posts] [t] ORDER BY id) as [__inner__] ORDER BY id DESC) as [__outer__] ORDER BY id ASC', $command->text); + + $command = $this->createFindCommand([ + 'select'=>'title', + ]); + $this->assertEquals('SELECT title FROM [dbo].[posts] [t]', $command->text); } public function testCommandBuilderNewMssql() { $this->db->method('getServerVersion')->willReturn('11'); + $command = $this->createFindCommand([ + 'limit'=>3, + ]); + $this->assertEquals('SELECT TOP 3 * FROM [dbo].[posts] [t]', $command->text); + $command = $this->createFindCommand([ 'select'=>'id, title', 'order'=>'title', 'limit'=>2, - 'offset'=>3 + 'offset'=>3, ]); $this->assertEquals('SELECT id, title FROM [dbo].[posts] [t] ORDER BY title OFFSET 3 ROWS FETCH NEXT 2 ROWS ONLY', $command->text); $command = $this->createFindCommand([ 'limit'=>2, - 'offset'=>3 + 'offset'=>3, ]); $this->assertEquals('SELECT * FROM [dbo].[posts] [t] ORDER BY id OFFSET 3 ROWS FETCH NEXT 2 ROWS ONLY', $command->text); + + + $command = $this->createFindCommand([ + 'select'=>'title', + 'offset'=>3, + ]); + $this->assertEquals('SELECT title FROM [dbo].[posts] [t] ORDER BY id OFFSET 3 ROWS', $command->text); + + $command = $this->createFindCommand([ + 'offset'=>3, + ]); + $this->assertEquals('SELECT * FROM [dbo].[posts] [t] ORDER BY id OFFSET 3 ROWS', $command->text); + + $command = $this->createFindCommand([ + 'select'=>'title', + ]); + $this->assertEquals('SELECT title FROM [dbo].[posts] [t]', $command->text); } /**