From 9175755303348f4e656752d3247043558201a92b Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 3 Aug 2016 18:02:02 +0300 Subject: [PATCH] Process LIMIT and OFFSET individually by using >= and <= instead of BETWEEN --- lib/Doctrine/DBAL/Platforms/DB2Platform.php | 13 ++++++++++--- .../Tests/DBAL/Functional/ModifyLimitQueryTest.php | 10 ++++++++++ .../Tests/DBAL/Platforms/DB2PlatformTest.php | 8 ++++---- 3 files changed, 24 insertions(+), 7 deletions(-) diff --git a/lib/Doctrine/DBAL/Platforms/DB2Platform.php b/lib/Doctrine/DBAL/Platforms/DB2Platform.php index c74e3c11c86..a958b306d85 100644 --- a/lib/Doctrine/DBAL/Platforms/DB2Platform.php +++ b/lib/Doctrine/DBAL/Platforms/DB2Platform.php @@ -775,12 +775,19 @@ protected function doModifyLimitQuery($query, $limit, $offset = null) return $query; } - $limit = (int) $limit; - $offset = (int) (($offset)?:0); + $where = array(); + + if ($offset !== null) { + $where[] = 'db22.DC_ROWNUM >= ' . ($offset + 1); + } + + if ($limit !== null) { + $where[] = 'db22.DC_ROWNUM <= ' . (($offset ?: 0) + $limit); + } // Todo OVER() needs ORDER BY data! $sql = 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM '. - 'FROM (' . $query . ') db21) db22 WHERE db22.DC_ROWNUM BETWEEN ' . ($offset+1) .' AND ' . ($offset+$limit); + 'FROM (' . $query . ') db21) db22 WHERE ' . implode(' AND ', $where); return $sql; } diff --git a/tests/Doctrine/Tests/DBAL/Functional/ModifyLimitQueryTest.php b/tests/Doctrine/Tests/DBAL/Functional/ModifyLimitQueryTest.php index 0361d696d9b..58ff7e2757e 100644 --- a/tests/Doctrine/Tests/DBAL/Functional/ModifyLimitQueryTest.php +++ b/tests/Doctrine/Tests/DBAL/Functional/ModifyLimitQueryTest.php @@ -144,6 +144,16 @@ public function testModifyLimitQueryLineBreaks() $this->assertLimitResult(array(2), $sql, 1, 1); } + public function testModifyLimitQueryZeroOffsetNoLimit() + { + $this->_conn->insert('modify_limit_table', array('test_int' => 1)); + $this->_conn->insert('modify_limit_table', array('test_int' => 2)); + + $sql = "SELECT test_int FROM modify_limit_table ORDER BY test_int ASC"; + + $this->assertLimitResult(array(1, 2), $sql, null, 0); + } + public function assertLimitResult($expectedResults, $sql, $limit, $offset, $deterministic = true) { $p = $this->_conn->getDatabasePlatform(); diff --git a/tests/Doctrine/Tests/DBAL/Platforms/DB2PlatformTest.php b/tests/Doctrine/Tests/DBAL/Platforms/DB2PlatformTest.php index e8b8916539a..1d5c63313f3 100644 --- a/tests/Doctrine/Tests/DBAL/Platforms/DB2PlatformTest.php +++ b/tests/Doctrine/Tests/DBAL/Platforms/DB2PlatformTest.php @@ -358,21 +358,21 @@ public function testModifiesLimitQuery() ); $this->assertEquals( - 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM BETWEEN 1 AND 10', + 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM >= 1 AND db22.DC_ROWNUM <= 10', $this->_platform->modifyLimitQuery('SELECT * FROM user', 10, 0) ); $this->assertEquals( - 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM BETWEEN 1 AND 10', + 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM <= 10', $this->_platform->modifyLimitQuery('SELECT * FROM user', 10) ); $this->assertEquals( - 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM BETWEEN 6 AND 15', + 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM >= 6 AND db22.DC_ROWNUM <= 15', $this->_platform->modifyLimitQuery('SELECT * FROM user', 10, 5) ); $this->assertEquals( - 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM BETWEEN 6 AND 5', + 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (SELECT * FROM user) db21) db22 WHERE db22.DC_ROWNUM >= 6 AND db22.DC_ROWNUM <= 5', $this->_platform->modifyLimitQuery('SELECT * FROM user', 0, 5) ); }