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

Use native IBM DB2 11 syntax for Top-N queries #5156

Merged
merged 1 commit into from
Jan 5, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
17 changes: 3 additions & 14 deletions src/Platforms/DB2Platform.php
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
28 changes: 0 additions & 28 deletions tests/Platforms/DB2PlatformTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -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());
Expand Down