From 48ead93eab4bd45277abfa186fe8b6711643f9b3 Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Thu, 30 Dec 2021 16:54:54 -0800 Subject: [PATCH] Use native IBM DB2 11 syntax for Top-N queries --- src/Platforms/DB2Platform.php | 17 +++-------------- tests/Platforms/DB2PlatformTest.php | 28 ---------------------------- 2 files changed, 3 insertions(+), 42 deletions(-) diff --git a/src/Platforms/DB2Platform.php b/src/Platforms/DB2Platform.php index b1e791b106c..8b7cd3a09f2 100644 --- a/src/Platforms/DB2Platform.php +++ b/src/Platforms/DB2Platform.php @@ -643,26 +643,15 @@ public function getTemporaryTableName(string $tableName): string protected function doModifyLimitQuery(string $query, ?int $limit, int $offset): string { - $where = []; - if ($offset > 0) { - $where[] = sprintf('db22.DC_ROWNUM >= %d', $offset + 1); + $query .= sprintf(' OFFSET %d ROWS', $offset); } if ($limit !== null) { - $where[] = sprintf('db22.DC_ROWNUM <= %d', $offset + $limit); - } - - if (empty($where)) { - return $query; + $query .= sprintf(' FETCH NEXT %d ROWS ONLY', $limit); } - // Todo OVER() needs ORDER BY data! - return sprintf( - 'SELECT db22.* FROM (SELECT db21.*, ROW_NUMBER() OVER() AS DC_ROWNUM FROM (%s) db21) db22 WHERE %s', - $query, - implode(' AND ', $where) - ); + return $query; } public function getLocateExpression(string $string, string $substring, ?string $start = null): string diff --git a/tests/Platforms/DB2PlatformTest.php b/tests/Platforms/DB2PlatformTest.php index 5df4ba6bfff..8a0b16a160b 100644 --- a/tests/Platforms/DB2PlatformTest.php +++ b/tests/Platforms/DB2PlatformTest.php @@ -392,34 +392,6 @@ public function testGeneratesSQLSnippets(): void self::assertEquals('SUBSTR(column, 5, 2)', $this->platform->getSubstringExpression('column', '5', '2')); } - public function testModifiesLimitQuery(): void - { - self::assertEquals( - 'SELECT * FROM user', - $this->platform->modifyLimitQuery('SELECT * FROM user', null, 0) - ); - - self::assertEquals( - '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) - ); - - self::assertEquals( - '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) - ); - self::assertEquals( - '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) - ); - } - public function testSupportsIdentityColumns(): void { self::assertTrue($this->platform->supportsIdentityColumns());