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 Oracle 12c syntax for Top-N queries #5150

Merged
merged 1 commit into from
Dec 30, 2021
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
27 changes: 4 additions & 23 deletions src/Platforms/OraclePlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -20,7 +20,6 @@
use function count;
use function explode;
use function implode;
use function preg_match;
use function sprintf;
use function str_contains;
use function strlen;
Expand Down Expand Up @@ -859,30 +858,12 @@ public function supportsCommentOnStatement(): bool

protected function doModifyLimitQuery(string $query, ?int $limit, int $offset): string
{
if ($limit === null && $offset <= 0) {
return $query;
if ($offset > 0) {
$query .= sprintf(' OFFSET %d ROWS', $offset);
}

if (preg_match('/^\s*SELECT/i', $query) === 1) {
if (preg_match('/\sFROM\s/i', $query) === 0) {
$query .= ' FROM dual';
}

$columns = ['a.*'];

if ($offset > 0) {
$columns[] = 'ROWNUM AS doctrine_rownum';
}

$query = sprintf('SELECT %s FROM (%s) a', implode(', ', $columns), $query);

if ($limit !== null) {
$query .= sprintf(' WHERE ROWNUM <= %d', $offset + $limit);
}

if ($offset > 0) {
$query = sprintf('SELECT * FROM (%s) WHERE doctrine_rownum >= %d', $query, $offset + 1);
}
if ($limit !== null) {
$query .= sprintf(' FETCH NEXT %d ROWS ONLY', $limit);
}

return $query;
Expand Down
48 changes: 0 additions & 48 deletions tests/Platforms/OraclePlatformTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -201,54 +201,6 @@ public static function getReturnsForeignKeyReferentialActionSQL(): iterable
];
}

public function testModifyLimitQuery(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10, 0);
self::assertEquals('SELECT a.* FROM (SELECT * FROM user) a WHERE ROWNUM <= 10', $sql);
}

public function testModifyLimitQueryWithEmptyOffset(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10);
self::assertEquals('SELECT a.* FROM (SELECT * FROM user) a WHERE ROWNUM <= 10', $sql);
}

public function testModifyLimitQueryWithNonEmptyOffset(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10, 10);

self::assertEquals(
'SELECT * FROM ('
. 'SELECT a.*, ROWNUM AS doctrine_rownum FROM (SELECT * FROM user) a WHERE ROWNUM <= 20'
. ') WHERE doctrine_rownum >= 11',
$sql
);
}

public function testModifyLimitQueryWithEmptyLimit(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user', null, 10);

self::assertEquals(
'SELECT * FROM ('
. 'SELECT a.*, ROWNUM AS doctrine_rownum FROM (SELECT * FROM user) a'
. ') WHERE doctrine_rownum >= 11',
$sql
);
}

public function testModifyLimitQueryWithAscOrderBy(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username ASC', 10);
self::assertEquals('SELECT a.* FROM (SELECT * FROM user ORDER BY username ASC) a WHERE ROWNUM <= 10', $sql);
}

public function testModifyLimitQueryWithDescOrderBy(): void
{
$sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10);
self::assertEquals('SELECT a.* FROM (SELECT * FROM user ORDER BY username DESC) a WHERE ROWNUM <= 10', $sql);
}

public function testGenerateTableWithAutoincrement(): void
{
$columnName = strtoupper('id' . uniqid());
Expand Down