From e360ba05143ca2132d56f2c91ef36cfc37b47780 Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 27 Nov 2019 17:50:21 -0800 Subject: [PATCH] Dropped SQL Server 2008 support --- .appveyor.yml | 5 - UPGRADE.md | 12 +- docs/en/reference/platforms.rst | 3 +- .../DBAL/Driver/AbstractSQLServerDriver.php | 38 +- .../Keywords/SQLServer2012Keywords.php | 37 -- .../Platforms/Keywords/SQLServerKeywords.php | 5 + .../DBAL/Platforms/SQLServer2012Platform.php | 143 ------- .../DBAL/Platforms/SQLServerPlatform.php | 215 +++++----- .../Console/Command/ReservedWordsCommand.php | 2 - .../Driver/AbstractSQLServerDriverTest.php | 20 +- .../AbstractSQLServerPlatformTestCase.php | 298 +++++++------- .../Platforms/SQLServer2012PlatformTest.php | 372 ------------------ .../DBAL/Platforms/SQLServerPlatformTest.php | 33 -- 13 files changed, 275 insertions(+), 908 deletions(-) delete mode 100644 lib/Doctrine/DBAL/Platforms/Keywords/SQLServer2012Keywords.php delete mode 100644 lib/Doctrine/DBAL/Platforms/SQLServer2012Platform.php delete mode 100644 tests/Doctrine/Tests/DBAL/Platforms/SQLServer2012PlatformTest.php diff --git a/.appveyor.yml b/.appveyor.yml index 352719e2617..2257d2b6e91 100644 --- a/.appveyor.yml +++ b/.appveyor.yml @@ -18,11 +18,6 @@ cache: ## Build matrix for lowest and highest possible targets environment: matrix: - - db: mssql - driver: sqlsrv - db_version: sql2008r2sp2 - coverage: yes - php: 7.3 - db: mssql driver: sqlsrv db_version: sql2012sp1 diff --git a/UPGRADE.md b/UPGRADE.md index 96e6d01614a..c6ecc04fca2 100644 --- a/UPGRADE.md +++ b/UPGRADE.md @@ -52,18 +52,22 @@ The following classes have been removed: * `Doctrine\DBAL\Platforms\Keywords\SQLAnywhere12Keywords` * `Doctrine\DBAL\Platforms\Keywords\SQLAnywhere16Keywords` -## BC BREAK: Removed support for SQL Server 2005 and older +## BC BREAK: Removed support for SQL Server 2008 and older -DBAL now requires SQL Server 2008 or newer, support for unmaintained versions has been dropped. -If you are using any of the legacy versions, you have to upgrade to newer SQL Server version (2012+ is recommended). -`Doctrine\DBAL\Platforms\SQLServerPlatform` and `Doctrine\DBAL\Platforms\Keywords\SQLServerKeywords` now represent the SQL Server 2008. +DBAL now requires SQL Server 2012 or newer, support for unmaintained versions has been dropped. +If you are using any of the legacy versions, you have to upgrade to a newer SQL Server version. +`Doctrine\DBAL\Platforms\SQLServerPlatform` and `Doctrine\DBAL\Platforms\Keywords\SQLServerKeywords` now represent SQL Server 2012. The following classes have been removed: * `Doctrine\DBAL\Platforms\SQLServer2005Platform` * `Doctrine\DBAL\Platforms\SQLServer2008Platform` + * `Doctrine\DBAL\Platforms\SQLServer2012Platform` * `Doctrine\DBAL\Platforms\Keywords\SQLServer2005Keywords` * `Doctrine\DBAL\Platforms\Keywords\SQLServer2008Keywords` + * `Doctrine\DBAL\Platforms\Keywords\SQLServer2012Keywords` + +The `AbstractSQLServerDriver` class and its subclasses no longer implement the `VersionAwarePlatformDriver` interface. ## BC BREAK: Removed support for PostgreSQL 9.2 and older diff --git a/docs/en/reference/platforms.rst b/docs/en/reference/platforms.rst index f2f36592e8e..142f6fd7550 100644 --- a/docs/en/reference/platforms.rst +++ b/docs/en/reference/platforms.rst @@ -50,8 +50,7 @@ Oracle Microsoft SQL Server ^^^^^^^^^^^^^^^^^^^^ -- ``SQLServerPlatform`` for version 2008 and above. -- ``SQLServer2012Platform`` for version 2012 and above. +- ``SQLServerPlatform`` for version 2012 and above. PostgreSQL ^^^^^^^^^^ diff --git a/lib/Doctrine/DBAL/Driver/AbstractSQLServerDriver.php b/lib/Doctrine/DBAL/Driver/AbstractSQLServerDriver.php index 1a86508549a..f010fc325c7 100644 --- a/lib/Doctrine/DBAL/Driver/AbstractSQLServerDriver.php +++ b/lib/Doctrine/DBAL/Driver/AbstractSQLServerDriver.php @@ -3,49 +3,15 @@ namespace Doctrine\DBAL\Driver; use Doctrine\DBAL\Connection; -use Doctrine\DBAL\DBALException; -use Doctrine\DBAL\Platforms\SQLServer2012Platform; +use Doctrine\DBAL\Driver; use Doctrine\DBAL\Platforms\SQLServerPlatform; use Doctrine\DBAL\Schema\SQLServerSchemaManager; -use Doctrine\DBAL\VersionAwarePlatformDriver; -use function preg_match; -use function version_compare; /** * Abstract base implementation of the {@link Doctrine\DBAL\Driver} interface for Microsoft SQL Server based drivers. */ -abstract class AbstractSQLServerDriver implements VersionAwarePlatformDriver +abstract class AbstractSQLServerDriver implements Driver { - /** - * {@inheritdoc} - */ - public function createDatabasePlatformForVersion($version) - { - if (! preg_match( - '/^(?P\d+)(?:\.(?P\d+)(?:\.(?P\d+)(?:\.(?P\d+))?)?)?/', - $version, - $versionParts - )) { - throw DBALException::invalidPlatformVersionSpecified( - $version, - '...' - ); - } - - $majorVersion = $versionParts['major']; - $minorVersion = $versionParts['minor'] ?? 0; - $patchVersion = $versionParts['patch'] ?? 0; - $buildVersion = $versionParts['build'] ?? 0; - $version = $majorVersion . '.' . $minorVersion . '.' . $patchVersion . '.' . $buildVersion; - - switch (true) { - case version_compare($version, '11.00.2100', '>='): - return new SQLServer2012Platform(); - default: - return new SQLServerPlatform(); - } - } - /** * {@inheritdoc} */ diff --git a/lib/Doctrine/DBAL/Platforms/Keywords/SQLServer2012Keywords.php b/lib/Doctrine/DBAL/Platforms/Keywords/SQLServer2012Keywords.php deleted file mode 100644 index d29225270aa..00000000000 --- a/lib/Doctrine/DBAL/Platforms/Keywords/SQLServer2012Keywords.php +++ /dev/null @@ -1,37 +0,0 @@ -getQuotedName($this) . - ' INCREMENT BY ' . $sequence->getAllocationSize(); - } - - /** - * {@inheritdoc} - */ - public function getCreateSequenceSQL(Sequence $sequence) - { - return 'CREATE SEQUENCE ' . $sequence->getQuotedName($this) . - ' START WITH ' . $sequence->getInitialValue() . - ' INCREMENT BY ' . $sequence->getAllocationSize() . - ' MINVALUE ' . $sequence->getInitialValue(); - } - - /** - * {@inheritdoc} - */ - public function getDropSequenceSQL($sequence) - { - if ($sequence instanceof Sequence) { - $sequence = $sequence->getQuotedName($this); - } - - return 'DROP SEQUENCE ' . $sequence; - } - - /** - * {@inheritdoc} - */ - public function getListSequencesSQL($database) - { - return 'SELECT seq.name, - CAST( - seq.increment AS VARCHAR(MAX) - ) AS increment, -- CAST avoids driver error for sql_variant type - CAST( - seq.start_value AS VARCHAR(MAX) - ) AS start_value -- CAST avoids driver error for sql_variant type - FROM sys.sequences AS seq'; - } - - /** - * {@inheritdoc} - */ - public function getSequenceNextValSQL($sequenceName) - { - return 'SELECT NEXT VALUE FOR ' . $sequenceName; - } - - /** - * {@inheritdoc} - */ - public function supportsSequences() - { - return true; - } - - /** - * {@inheritdoc} - * - * Returns Microsoft SQL Server 2012 specific keywords class - */ - protected function getReservedKeywordsClass() - { - return Keywords\SQLServer2012Keywords::class; - } - - /** - * {@inheritdoc} - */ - protected function doModifyLimitQuery($query, $limit, $offset = null) - { - if ($limit === null && $offset <= 0) { - return $query; - } - - // Queries using OFFSET... FETCH MUST have an ORDER BY clause - // Find the position of the last instance of ORDER BY and ensure it is not within a parenthetical statement - // but can be in a newline - $matches = []; - $matchesCount = preg_match_all('/[\\s]+order\\s+by\\s/im', $query, $matches, PREG_OFFSET_CAPTURE); - $orderByPos = false; - if ($matchesCount > 0) { - $orderByPos = $matches[0][($matchesCount - 1)][1]; - } - - if ($orderByPos === false - || substr_count($query, '(', $orderByPos) - substr_count($query, ')', $orderByPos) - ) { - if (preg_match('/^SELECT\s+DISTINCT/im', $query)) { - // SQL Server won't let us order by a non-selected column in a DISTINCT query, - // so we have to do this madness. This says, order by the first column in the - // result. SQL Server's docs say that a nonordered query's result order is non- - // deterministic anyway, so this won't do anything that a bunch of update and - // deletes to the table wouldn't do anyway. - $query .= ' ORDER BY 1'; - } else { - // In another DBMS, we could do ORDER BY 0, but SQL Server gets angry if you - // use constant expressions in the order by list. - $query .= ' ORDER BY (SELECT 0)'; - } - } - - if ($offset === null) { - $offset = 0; - } - - // This looks somewhat like MYSQL, but limit/offset are in inverse positions - // Supposedly SQL:2008 core standard. - // Per TSQL spec, FETCH NEXT n ROWS ONLY is not valid without OFFSET n ROWS. - $query .= ' OFFSET ' . (int) $offset . ' ROWS'; - - if ($limit !== null) { - $query .= ' FETCH NEXT ' . (int) $limit . ' ROWS ONLY'; - } - - return $query; - } -} diff --git a/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php b/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php index c29d488cbbb..d17229d5cc5 100644 --- a/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php +++ b/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php @@ -8,9 +8,11 @@ use Doctrine\DBAL\Schema\ForeignKeyConstraint; use Doctrine\DBAL\Schema\Identifier; use Doctrine\DBAL\Schema\Index; +use Doctrine\DBAL\Schema\Sequence; use Doctrine\DBAL\Schema\Table; use Doctrine\DBAL\Schema\TableDiff; use InvalidArgumentException; +use const PREG_OFFSET_CAPTURE; use function array_merge; use function array_unique; use function array_values; @@ -25,14 +27,11 @@ use function is_numeric; use function is_string; use function preg_match; +use function preg_match_all; use function sprintf; use function str_replace; -use function stripos; -use function stristr; -use function strlen; use function strpos; use function strtoupper; -use function substr; use function substr_count; /** @@ -145,6 +144,69 @@ public function supportsColumnCollation() return true; } + /** + * {@inheritdoc} + */ + public function supportsSequences() : bool + { + return true; + } + + /** + * {@inheritdoc} + */ + public function getAlterSequenceSQL(Sequence $sequence) : string + { + return 'ALTER SEQUENCE ' . $sequence->getQuotedName($this) . + ' INCREMENT BY ' . $sequence->getAllocationSize(); + } + + /** + * {@inheritdoc} + */ + public function getCreateSequenceSQL(Sequence $sequence) : string + { + return 'CREATE SEQUENCE ' . $sequence->getQuotedName($this) . + ' START WITH ' . $sequence->getInitialValue() . + ' INCREMENT BY ' . $sequence->getAllocationSize() . + ' MINVALUE ' . $sequence->getInitialValue(); + } + + /** + * {@inheritdoc} + */ + public function getDropSequenceSQL($sequence) : string + { + if ($sequence instanceof Sequence) { + $sequence = $sequence->getQuotedName($this); + } + + return 'DROP SEQUENCE ' . $sequence; + } + + /** + * {@inheritdoc} + */ + public function getListSequencesSQL($database) + { + return 'SELECT seq.name, + CAST( + seq.increment AS VARCHAR(MAX) + ) AS increment, -- CAST avoids driver error for sql_variant type + CAST( + seq.start_value AS VARCHAR(MAX) + ) AS start_value -- CAST avoids driver error for sql_variant type + FROM sys.sequences AS seq'; + } + + /** + * {@inheritdoc} + */ + public function getSequenceNextValSQL($sequenceName) + { + return 'SELECT NEXT VALUE FOR ' . $sequenceName; + } + /** * {@inheritDoc} */ @@ -1271,132 +1333,47 @@ public function getBooleanTypeDeclarationSQL(array $field) */ protected function doModifyLimitQuery($query, $limit, $offset = null) { - $where = []; - - if ($offset > 0) { - $where[] = sprintf('doctrine_rownum >= %d', $offset + 1); - } - - if ($limit !== null) { - $where[] = sprintf('doctrine_rownum <= %d', $offset + $limit); - $top = sprintf('TOP %d', $offset + $limit); - } else { - $top = 'TOP 9223372036854775807'; - } - - if (empty($where)) { + if ($limit === null && $offset <= 0) { return $query; } - // We'll find a SELECT or SELECT distinct and prepend TOP n to it - // Even if the TOP n is very large, the use of a CTE will - // allow the SQL Server query planner to optimize it so it doesn't - // actually scan the entire range covered by the TOP clause. - if (! preg_match('/^(\s*SELECT\s+(?:DISTINCT\s+)?)(.*)$/is', $query, $matches)) { - return $query; + // Queries using OFFSET... FETCH MUST have an ORDER BY clause + // Find the position of the last instance of ORDER BY and ensure it is not within a parenthetical statement + // but can be in a newline + $matches = []; + $matchesCount = preg_match_all('/[\\s]+order\\s+by\\s/im', $query, $matches, PREG_OFFSET_CAPTURE); + $orderByPos = false; + if ($matchesCount > 0) { + $orderByPos = $matches[0][($matchesCount - 1)][1]; } - $query = $matches[1] . $top . ' ' . $matches[2]; - - if (stristr($query, 'ORDER BY')) { - // Inner order by is not valid in SQL Server for our purposes - // unless it's in a TOP N subquery. - $query = $this->scrubInnerOrderBy($query); - } - - // Build a new limited query around the original, using a CTE - return sprintf( - 'WITH dctrn_cte AS (%s) ' - . 'SELECT * FROM (' - . 'SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte' - . ') AS doctrine_tbl ' - . 'WHERE %s ORDER BY doctrine_rownum ASC', - $query, - implode(' AND ', $where) - ); - } - - /** - * Remove ORDER BY clauses in subqueries - they're not supported by SQL Server. - * Caveat: will leave ORDER BY in TOP N subqueries. - * - * @param string $query - * - * @return string - */ - private function scrubInnerOrderBy($query) - { - $count = substr_count(strtoupper($query), 'ORDER BY'); - $offset = 0; - - while ($count-- > 0) { - $orderByPos = stripos($query, ' ORDER BY', $offset); - if ($orderByPos === false) { - break; + if ($orderByPos === false + || substr_count($query, '(', $orderByPos) - substr_count($query, ')', $orderByPos) + ) { + if (preg_match('/^SELECT\s+DISTINCT/im', $query)) { + // SQL Server won't let us order by a non-selected column in a DISTINCT query, + // so we have to do this madness. This says, order by the first column in the + // result. SQL Server's docs say that a nonordered query's result order is non- + // deterministic anyway, so this won't do anything that a bunch of update and + // deletes to the table wouldn't do anyway. + $query .= ' ORDER BY 1'; + } else { + // In another DBMS, we could do ORDER BY 0, but SQL Server gets angry if you + // use constant expressions in the order by list. + $query .= ' ORDER BY (SELECT 0)'; } - - $qLen = strlen($query); - $parenCount = 0; - $currentPosition = $orderByPos; - - while ($parenCount >= 0 && $currentPosition < $qLen) { - if ($query[$currentPosition] === '(') { - $parenCount++; - } elseif ($query[$currentPosition] === ')') { - $parenCount--; - } - - $currentPosition++; - } - - if ($this->isOrderByInTopNSubquery($query, $orderByPos)) { - // If the order by clause is in a TOP N subquery, do not remove - // it and continue iteration from the current position. - $offset = $currentPosition; - continue; - } - - if ($currentPosition >= $qLen - 1) { - continue; - } - - $query = substr($query, 0, $orderByPos) . substr($query, $currentPosition - 1); - $offset = $orderByPos; } - return $query; - } + // This looks somewhat like MYSQL, but limit/offset are in inverse positions + // Supposedly SQL:2008 core standard. + // Per TSQL spec, FETCH NEXT n ROWS ONLY is not valid without OFFSET n ROWS. + $query .= sprintf(' OFFSET %d ROWS', $offset); - /** - * Check an ORDER BY clause to see if it is in a TOP N query or subquery. - * - * @param string $query The query - * @param int $currentPosition Start position of ORDER BY clause - * - * @return bool true if ORDER BY is in a TOP N query, false otherwise - */ - private function isOrderByInTopNSubquery($query, $currentPosition) - { - // Grab query text on the same nesting level as the ORDER BY clause we're examining. - $subQueryBuffer = ''; - $parenCount = 0; - - // If $parenCount goes negative, we've exited the subquery we're examining. - // If $currentPosition goes negative, we've reached the beginning of the query. - while ($parenCount >= 0 && $currentPosition >= 0) { - if ($query[$currentPosition] === '(') { - $parenCount--; - } elseif ($query[$currentPosition] === ')') { - $parenCount++; - } - - // Only yank query text on the same nesting level as the ORDER BY clause. - $subQueryBuffer = ($parenCount === 0 ? $query[$currentPosition] : ' ') . $subQueryBuffer; - - $currentPosition--; + if ($limit !== null) { + $query .= sprintf(' FETCH NEXT %d ROWS ONLY', $limit); } - return (bool) preg_match('/SELECT\s+(DISTINCT\s+)?TOP\s/i', $subQueryBuffer); + return $query; } /** diff --git a/lib/Doctrine/DBAL/Tools/Console/Command/ReservedWordsCommand.php b/lib/Doctrine/DBAL/Tools/Console/Command/ReservedWordsCommand.php index 13d885fdb6c..60c8f021c74 100644 --- a/lib/Doctrine/DBAL/Tools/Console/Command/ReservedWordsCommand.php +++ b/lib/Doctrine/DBAL/Tools/Console/Command/ReservedWordsCommand.php @@ -14,7 +14,6 @@ use Doctrine\DBAL\Platforms\Keywords\ReservedKeywordsValidator; use Doctrine\DBAL\Platforms\Keywords\SQLAnywhereKeywords; use Doctrine\DBAL\Platforms\Keywords\SQLiteKeywords; -use Doctrine\DBAL\Platforms\Keywords\SQLServer2012Keywords; use Doctrine\DBAL\Platforms\Keywords\SQLServerKeywords; use InvalidArgumentException; use Symfony\Component\Console\Command\Command; @@ -40,7 +39,6 @@ class ReservedWordsCommand extends Command 'sqlanywhere' => SQLAnywhereKeywords::class, 'sqlite' => SQLiteKeywords::class, 'sqlserver' => SQLServerKeywords::class, - 'sqlserver2012' => SQLServer2012Keywords::class, ]; /** diff --git a/tests/Doctrine/Tests/DBAL/Driver/AbstractSQLServerDriverTest.php b/tests/Doctrine/Tests/DBAL/Driver/AbstractSQLServerDriverTest.php index 330b4b5e4d8..a0ea28b63ab 100644 --- a/tests/Doctrine/Tests/DBAL/Driver/AbstractSQLServerDriverTest.php +++ b/tests/Doctrine/Tests/DBAL/Driver/AbstractSQLServerDriverTest.php @@ -6,7 +6,6 @@ use Doctrine\DBAL\Driver; use Doctrine\DBAL\Driver\AbstractSQLServerDriver; use Doctrine\DBAL\Platforms\AbstractPlatform; -use Doctrine\DBAL\Platforms\SQLServer2012Platform; use Doctrine\DBAL\Platforms\SQLServerPlatform; use Doctrine\DBAL\Schema\AbstractSchemaManager; use Doctrine\DBAL\Schema\SQLServerSchemaManager; @@ -34,24 +33,7 @@ protected function createSchemaManager(Connection $connection) : AbstractSchemaM protected function getDatabasePlatformsForVersions() : array { return [ - ['10', SQLServerPlatform::class], - ['10.00', SQLServerPlatform::class], - ['10.00.0', SQLServerPlatform::class], - ['10.00.1599', SQLServerPlatform::class], - ['10.00.1599.99', SQLServerPlatform::class], - ['10.00.1600', SQLServerPlatform::class], - ['10.00.1600.0', SQLServerPlatform::class], - ['10.00.1600.99', SQLServerPlatform::class], - ['10.00.1601', SQLServerPlatform::class], - ['10.10', SQLServerPlatform::class], - ['10.10.9999', SQLServerPlatform::class], - ['11.00.2099', SQLServerPlatform::class], - ['11.00.2099.99', SQLServerPlatform::class], - ['11.00.2100', SQLServer2012Platform::class], - ['11.00.2100.0', SQLServer2012Platform::class], - ['11.00.2100.99', SQLServer2012Platform::class], - ['11.00.2101', SQLServer2012Platform::class], - ['12', SQLServer2012Platform::class], + ['12', SQLServerPlatform::class], ]; } } diff --git a/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php b/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php index 46627bd8cf2..75e54470505 100644 --- a/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php +++ b/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php @@ -6,11 +6,11 @@ use Doctrine\DBAL\Schema\Column; use Doctrine\DBAL\Schema\ColumnDiff; use Doctrine\DBAL\Schema\Index; +use Doctrine\DBAL\Schema\Sequence; use Doctrine\DBAL\Schema\Table; use Doctrine\DBAL\Schema\TableDiff; use Doctrine\DBAL\TransactionIsolationLevel; use Doctrine\DBAL\Types\Type; -use function sprintf; abstract class AbstractSQLServerPlatformTestCase extends AbstractPlatformTestCase { @@ -184,115 +184,77 @@ public function getGenerateForeignKeySql() : string public function testModifyLimitQuery() : void { - $querySql = 'SELECT * FROM user'; - $alteredSql = 'SELECT TOP 10 * FROM user'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 0); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10, 0); + self::assertEquals('SELECT * FROM user ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithEmptyOffset() : void { - $querySql = 'SELECT * FROM user'; - $alteredSql = 'SELECT TOP 10 * FROM user'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10); + self::assertEquals('SELECT * FROM user ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithOffset() : void { - if (! $this->platform->supportsLimitOffset()) { - $this->markTestSkipped(sprintf('Platform "%s" does not support offsets in result limiting.', $this->platform->getName())); - } - - $querySql = 'SELECT * FROM user ORDER BY username DESC'; - $alteredSql = 'SELECT TOP 15 * FROM user ORDER BY username DESC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 5); - - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10, 5); + self::assertEquals('SELECT * FROM user ORDER BY username DESC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithAscOrderBy() : void { - $querySql = 'SELECT * FROM user ORDER BY username ASC'; - $alteredSql = 'SELECT TOP 10 * FROM user ORDER BY username ASC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username ASC', 10); + self::assertEquals('SELECT * FROM user ORDER BY username ASC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithLowercaseOrderBy() : void { - $querySql = 'SELECT * FROM user order by username'; - $alteredSql = 'SELECT TOP 10 * FROM user order by username'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user order by username', 10); + self::assertEquals('SELECT * FROM user order by username OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithDescOrderBy() : void { - $querySql = 'SELECT * FROM user ORDER BY username DESC'; - $alteredSql = 'SELECT TOP 10 * FROM user ORDER BY username DESC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10); + self::assertEquals('SELECT * FROM user ORDER BY username DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithMultipleOrderBy() : void { - $querySql = 'SELECT * FROM user ORDER BY username DESC, usereamil ASC'; - $alteredSql = 'SELECT TOP 10 * FROM user ORDER BY username DESC, usereamil ASC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC, usereamil ASC', 10); + self::assertEquals('SELECT * FROM user ORDER BY username DESC, usereamil ASC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithSubSelect() : void { - $querySql = 'SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result'; - $alteredSql = 'SELECT TOP 10 * FROM (SELECT u.id as uid, u.name as uname) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result', 10); + self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithSubSelectAndOrder() : void { - $querySql = 'SELECT * FROM (SELECT u.id as uid, u.name as uname ORDER BY u.name DESC) dctrn_result'; - $alteredSql = 'SELECT TOP 10 * FROM (SELECT u.id as uid, u.name as uname) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC', 10); + self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - $querySql = 'SELECT * FROM (SELECT u.id, u.name ORDER BY u.name DESC) dctrn_result'; - $alteredSql = 'SELECT TOP 10 * FROM (SELECT u.id, u.name) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC', 10); + self::assertEquals('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithSubSelectAndMultipleOrder() : void { - if (! $this->platform->supportsLimitOffset()) { - $this->markTestSkipped(sprintf('Platform "%s" does not support offsets in result limiting.', $this->platform->getName())); - } - - $querySql = 'SELECT * FROM (SELECT u.id as uid, u.name as uname ORDER BY u.name DESC, id ASC) dctrn_result'; - $alteredSql = 'SELECT TOP 15 * FROM (SELECT u.id as uid, u.name as uname) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 5); - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC, uid ASC', 10, 5); + self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC, uid ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - $querySql = 'SELECT * FROM (SELECT u.id uid, u.name uname ORDER BY u.name DESC, id ASC) dctrn_result'; - $alteredSql = 'SELECT TOP 15 * FROM (SELECT u.id uid, u.name uname) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 5); - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id uid, u.name uname) dctrn_result ORDER BY uname DESC, uid ASC', 10, 5); + self::assertEquals('SELECT * FROM (SELECT u.id uid, u.name uname) dctrn_result ORDER BY uname DESC, uid ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - $querySql = 'SELECT * FROM (SELECT u.id, u.name ORDER BY u.name DESC, id ASC) dctrn_result'; - $alteredSql = 'SELECT TOP 15 * FROM (SELECT u.id, u.name) dctrn_result'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 5); - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC, id ASC', 10, 5); + self::assertEquals('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC, id ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } public function testModifyLimitQueryWithFromColumnNames() : void { - $querySql = 'SELECT a.fromFoo, fromBar FROM foo'; - $alteredSql = 'SELECT TOP 10 a.fromFoo, fromBar FROM foo'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $sql = $this->platform->modifyLimitQuery('SELECT a.fromFoo, fromBar FROM foo', 10); + self::assertEquals('SELECT a.fromFoo, fromBar FROM foo ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); } /** @@ -305,13 +267,15 @@ public function testModifyLimitQueryWithExtraLongQuery() : void $query .= 'AND (table2.column2 = table7.column7) AND (table2.column2 = table8.column8) AND (table3.column3 = table4.column4) AND (table3.column3 = table5.column5) AND (table3.column3 = table6.column6) AND (table3.column3 = table7.column7) AND (table3.column3 = table8.column8) AND (table4.column4 = table5.column5) AND (table4.column4 = table6.column6) AND (table4.column4 = table7.column7) AND (table4.column4 = table8.column8) '; $query .= 'AND (table5.column5 = table6.column6) AND (table5.column5 = table7.column7) AND (table5.column5 = table8.column8) AND (table6.column6 = table7.column7) AND (table6.column6 = table8.column8) AND (table7.column7 = table8.column8)'; - $alteredSql = 'SELECT TOP 10 table1.column1, table2.column2, table3.column3, table4.column4, table5.column5, table6.column6, table7.column7, table8.column8 FROM table1, table2, table3, table4, table5, table6, table7, table8 '; - $alteredSql .= 'WHERE (table1.column1 = table2.column2) AND (table1.column1 = table3.column3) AND (table1.column1 = table4.column4) AND (table1.column1 = table5.column5) AND (table1.column1 = table6.column6) AND (table1.column1 = table7.column7) AND (table1.column1 = table8.column8) AND (table2.column2 = table3.column3) AND (table2.column2 = table4.column4) AND (table2.column2 = table5.column5) AND (table2.column2 = table6.column6) '; - $alteredSql .= 'AND (table2.column2 = table7.column7) AND (table2.column2 = table8.column8) AND (table3.column3 = table4.column4) AND (table3.column3 = table5.column5) AND (table3.column3 = table6.column6) AND (table3.column3 = table7.column7) AND (table3.column3 = table8.column8) AND (table4.column4 = table5.column5) AND (table4.column4 = table6.column6) AND (table4.column4 = table7.column7) AND (table4.column4 = table8.column8) '; - $alteredSql .= 'AND (table5.column5 = table6.column6) AND (table5.column5 = table7.column7) AND (table5.column5 = table8.column8) AND (table6.column6 = table7.column7) AND (table6.column6 = table8.column8) AND (table7.column7 = table8.column8)'; - $sql = $this->platform->modifyLimitQuery($query, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + + $expected = 'SELECT table1.column1, table2.column2, table3.column3, table4.column4, table5.column5, table6.column6, table7.column7, table8.column8 FROM table1, table2, table3, table4, table5, table6, table7, table8 '; + $expected .= 'WHERE (table1.column1 = table2.column2) AND (table1.column1 = table3.column3) AND (table1.column1 = table4.column4) AND (table1.column1 = table5.column5) AND (table1.column1 = table6.column6) AND (table1.column1 = table7.column7) AND (table1.column1 = table8.column8) AND (table2.column2 = table3.column3) AND (table2.column2 = table4.column4) AND (table2.column2 = table5.column5) AND (table2.column2 = table6.column6) '; + $expected .= 'AND (table2.column2 = table7.column7) AND (table2.column2 = table8.column8) AND (table3.column3 = table4.column4) AND (table3.column3 = table5.column5) AND (table3.column3 = table6.column6) AND (table3.column3 = table7.column7) AND (table3.column3 = table8.column8) AND (table4.column4 = table5.column5) AND (table4.column4 = table6.column6) AND (table4.column4 = table7.column7) AND (table4.column4 = table8.column8) '; + $expected .= 'AND (table5.column5 = table6.column6) AND (table5.column5 = table7.column7) AND (table5.column5 = table8.column8) AND (table6.column6 = table7.column7) AND (table6.column6 = table8.column8) AND (table7.column7 = table8.column8) '; + $expected .= 'ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; + + self::assertEquals($expected, $sql); } /** @@ -319,15 +283,11 @@ public function testModifyLimitQueryWithExtraLongQuery() : void */ public function testModifyLimitQueryWithOrderByClause() : void { - if (! $this->platform->supportsLimitOffset()) { - $this->markTestSkipped(sprintf('Platform "%s" does not support offsets in result limiting.', $this->platform->getName())); - } + $sql = 'SELECT m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC'; + $expected = 'SELECT m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY'; + $actual = $this->platform->modifyLimitQuery($sql, 10, 5); - $sql = 'SELECT m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC'; - $alteredSql = 'SELECT TOP 15 m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC'; - $actual = $this->platform->modifyLimitQuery($sql, 10, 5); - - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $actual); + self::assertEquals($expected, $actual); } /** @@ -335,23 +295,28 @@ public function testModifyLimitQueryWithOrderByClause() : void */ public function testModifyLimitQueryWithSubSelectInSelectList() : void { - $querySql = 'SELECT ' . + $sql = $this->platform->modifyLimitQuery( + 'SELECT ' . 'u.id, ' . '(u.foo/2) foodiv, ' . 'CONCAT(u.bar, u.baz) barbaz, ' . '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . 'FROM user u ' . - "WHERE u.status = 'disabled'"; - $alteredSql = 'SELECT TOP 10 ' . + "WHERE u.status = 'disabled'", + 10 + ); + + self::assertEquals( + 'SELECT ' . 'u.id, ' . '(u.foo/2) foodiv, ' . 'CONCAT(u.bar, u.baz) barbaz, ' . '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . 'FROM user u ' . - "WHERE u.status = 'disabled'"; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + "WHERE u.status = 'disabled' " . + 'ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', + $sql + ); } /** @@ -359,28 +324,31 @@ public function testModifyLimitQueryWithSubSelectInSelectList() : void */ public function testModifyLimitQueryWithSubSelectInSelectListAndOrderByClause() : void { - if (! $this->platform->supportsLimitOffset()) { - $this->markTestSkipped(sprintf('Platform "%s" does not support offsets in result limiting.', $this->platform->getName())); - } - - $querySql = 'SELECT ' . + $sql = $this->platform->modifyLimitQuery( + 'SELECT ' . 'u.id, ' . '(u.foo/2) foodiv, ' . 'CONCAT(u.bar, u.baz) barbaz, ' . '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . 'FROM user u ' . "WHERE u.status = 'disabled' " . - 'ORDER BY u.username DESC'; - $alteredSql = 'SELECT TOP 15 ' . + 'ORDER BY u.username DESC', + 10, + 5 + ); + + self::assertEquals( + 'SELECT ' . 'u.id, ' . '(u.foo/2) foodiv, ' . 'CONCAT(u.bar, u.baz) barbaz, ' . '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . 'FROM user u ' . "WHERE u.status = 'disabled' " . - 'ORDER BY u.username DESC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10, 5); - $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); + 'ORDER BY u.username DESC ' . + 'OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', + $sql + ); } /** @@ -388,20 +356,27 @@ public function testModifyLimitQueryWithSubSelectInSelectListAndOrderByClause() */ public function testModifyLimitQueryWithAggregateFunctionInOrderByClause() : void { - $querySql = 'SELECT ' . + $sql = $this->platform->modifyLimitQuery( + 'SELECT ' . 'MAX(heading_id) aliased, ' . 'code ' . 'FROM operator_model_operator ' . 'GROUP BY code ' . - 'ORDER BY MAX(heading_id) DESC'; - $alteredSql = 'SELECT TOP 1 ' . + 'ORDER BY MAX(heading_id) DESC', + 1, + 0 + ); + + self::assertEquals( + 'SELECT ' . 'MAX(heading_id) aliased, ' . 'code ' . 'FROM operator_model_operator ' . 'GROUP BY code ' . - 'ORDER BY MAX(heading_id) DESC'; - $sql = $this->platform->modifyLimitQuery($querySql, 1, 0); - $this->expectCteWithMaxRowNum($alteredSql, 1, $sql); + 'ORDER BY MAX(heading_id) DESC ' . + 'OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY', + $sql + ); } /** @@ -413,19 +388,18 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromBas . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1 ' . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id ' - . 'ORDER BY t1.id ASC' + . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' . 'ORDER BY id_0 ASC'; - $alteredSql = 'SELECT DISTINCT TOP 5 id_0, name_1 ' + $alteredSql = 'SELECT DISTINCT id_0, name_1 ' . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1 ' . 'FROM table_parent t1 ' . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' - . 'ORDER BY id_0 ASC'; + . 'ORDER BY id_0 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; $sql = $this->platform->modifyLimitQuery($querySql, 5); - $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); + self::assertEquals($alteredSql, $sql); } /** @@ -437,19 +411,18 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromJoi . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1 ' . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id ' - . 'ORDER BY t2.name ASC' + . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' . 'ORDER BY name_1 ASC'; - $alteredSql = 'SELECT DISTINCT TOP 5 id_0, name_1 ' + $alteredSql = 'SELECT DISTINCT id_0, name_1 ' . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1 ' . 'FROM table_parent t1 ' . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' - . 'ORDER BY name_1 ASC'; + . 'ORDER BY name_1 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; $sql = $this->platform->modifyLimitQuery($querySql, 5); - $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); + self::assertEquals($alteredSql, $sql); } /** @@ -461,19 +434,18 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnsFromBo . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 ' . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id ' - . 'ORDER BY t2.name ASC, t2.foo DESC' + . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' . 'ORDER BY name_1 ASC, foo_2 DESC'; - $alteredSql = 'SELECT DISTINCT TOP 5 id_0, name_1, foo_2 ' + $alteredSql = 'SELECT DISTINCT id_0, name_1, foo_2 ' . 'FROM (' . 'SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 ' . 'FROM table_parent t1 ' . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' . ') dctrn_result ' - . 'ORDER BY name_1 ASC, foo_2 DESC'; + . 'ORDER BY name_1 ASC, foo_2 DESC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; $sql = $this->platform->modifyLimitQuery($querySql, 5); - $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); + self::assertEquals($alteredSql, $sql); } public function testModifyLimitSubquerySimple() : void @@ -481,10 +453,10 @@ public function testModifyLimitSubquerySimple() : void $querySql = 'SELECT DISTINCT id_0 FROM ' . '(SELECT k0_.id AS id_0, k0_.field AS field_1 ' . 'FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result'; - $alteredSql = 'SELECT DISTINCT TOP 20 id_0 FROM (SELECT k0_.id AS id_0, k0_.field AS field_1 ' - . 'FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result'; + $alteredSql = 'SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0, k0_.field AS field_1 ' + . 'FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result ORDER BY 1 OFFSET 0 ROWS FETCH NEXT 20 ROWS ONLY'; $sql = $this->platform->modifyLimitQuery($querySql, 20); - $this->expectCteWithMaxRowNum($alteredSql, 20, $sql); + self::assertEquals($alteredSql, $sql); } /** @@ -1453,15 +1425,50 @@ protected function getGeneratesAlterTableRenameIndexUsedByForeignKeySQL() : arra public function testModifyLimitQueryWithTopNSubQueryWithOrderBy() : void { - $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC)'; - $alteredSql = 'SELECT TOP 10 * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC)'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC)'; + $expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; + $sql = $this->platform->modifyLimitQuery($querySql, 10); + self::assertEquals($expectedSql, $sql); + + $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC'; + $expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; + $sql = $this->platform->modifyLimitQuery($querySql, 10); + self::assertEquals($expectedSql, $sql); + } + + public function testModifyLimitQueryWithFromSubquery() : void + { + $sql = $this->platform->modifyLimitQuery('SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result', 10); + + $expected = 'SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY 1 OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; + + self::assertEquals($sql, $expected); + } + + public function testModifyLimitQueryWithFromSubqueryAndOrder() : void + { + $sql = $this->platform->modifyLimitQuery('SELECT DISTINCT id_0, value_1 FROM (SELECT k0_.id AS id_0, k0_.value AS value_1 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY value_1 DESC', 10); + + $expected = 'SELECT DISTINCT id_0, value_1 FROM (SELECT k0_.id AS id_0, k0_.value AS value_1 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY value_1 DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC'; - $alteredSql = 'SELECT TOP 10 * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); + self::assertEquals($sql, $expected); + } + + public function testModifyLimitQueryWithComplexOrderByExpression() : void + { + $sql = $this->platform->modifyLimitQuery('SELECT * FROM table ORDER BY (table.x * table.y) DESC', 10); + + $expected = 'SELECT * FROM table ORDER BY (table.x * table.y) DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; + + self::assertEquals($sql, $expected); + } + + public function testModifyLimitQueryWithNewlineBeforeOrderBy() : void + { + $querySql = "SELECT * FROM test\nORDER BY col DESC"; + $expectedSql = "SELECT * FROM test\nORDER BY col DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY"; + $sql = $this->platform->modifyLimitQuery($querySql, 10); + self::assertEquals($expectedSql, $sql); } /** @@ -1575,15 +1582,34 @@ public function testGetCreateTableSQLWithColumnCollation() : void ); } - private function expectCteWithMaxRowNum(string $expectedSql, int $expectedMax, string $sql) : void + public function testSupportsSequences() : void { - $pattern = 'WITH dctrn_cte AS (%s) SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte) AS doctrine_tbl WHERE doctrine_rownum <= %d ORDER BY doctrine_rownum ASC'; - self::assertEquals(sprintf($pattern, $expectedSql, $expectedMax), $sql); + self::assertTrue($this->platform->supportsSequences()); } - private function expectCteWithMinAndMaxRowNums(string $expectedSql, int $expectedMin, int $expectedMax, string $sql) : void + public function testDoesNotPreferSequences() : void { - $pattern = 'WITH dctrn_cte AS (%s) SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte) AS doctrine_tbl WHERE doctrine_rownum >= %d AND doctrine_rownum <= %d ORDER BY doctrine_rownum ASC'; - self::assertEquals(sprintf($pattern, $expectedSql, $expectedMin, $expectedMax), $sql); + self::assertFalse($this->platform->prefersSequences()); + } + + public function testGeneratesSequenceSqlCommands() : void + { + $sequence = new Sequence('myseq', 20, 1); + self::assertEquals( + 'CREATE SEQUENCE myseq START WITH 1 INCREMENT BY 20 MINVALUE 1', + $this->platform->getCreateSequenceSQL($sequence) + ); + self::assertEquals( + 'ALTER SEQUENCE myseq INCREMENT BY 20', + $this->platform->getAlterSequenceSQL($sequence) + ); + self::assertEquals( + 'DROP SEQUENCE myseq', + $this->platform->getDropSequenceSQL('myseq') + ); + self::assertEquals( + 'SELECT NEXT VALUE FOR myseq', + $this->platform->getSequenceNextValSQL('myseq') + ); } } diff --git a/tests/Doctrine/Tests/DBAL/Platforms/SQLServer2012PlatformTest.php b/tests/Doctrine/Tests/DBAL/Platforms/SQLServer2012PlatformTest.php deleted file mode 100644 index e6d4975daed..00000000000 --- a/tests/Doctrine/Tests/DBAL/Platforms/SQLServer2012PlatformTest.php +++ /dev/null @@ -1,372 +0,0 @@ -platform->supportsSequences()); - } - - public function testDoesNotPreferSequences() : void - { - self::assertFalse($this->platform->prefersSequences()); - } - - public function testGeneratesSequenceSqlCommands() : void - { - $sequence = new Sequence('myseq', 20, 1); - self::assertEquals( - 'CREATE SEQUENCE myseq START WITH 1 INCREMENT BY 20 MINVALUE 1', - $this->platform->getCreateSequenceSQL($sequence) - ); - self::assertEquals( - 'ALTER SEQUENCE myseq INCREMENT BY 20', - $this->platform->getAlterSequenceSQL($sequence) - ); - self::assertEquals( - 'DROP SEQUENCE myseq', - $this->platform->getDropSequenceSQL('myseq') - ); - self::assertEquals( - 'SELECT NEXT VALUE FOR myseq', - $this->platform->getSequenceNextValSQL('myseq') - ); - } - - public function testModifyLimitQuery() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10, 0); - self::assertEquals('SELECT * FROM user ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithEmptyOffset() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user', 10); - self::assertEquals('SELECT * FROM user ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithOffset() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10, 5); - self::assertEquals('SELECT * FROM user ORDER BY username DESC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithAscOrderBy() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username ASC', 10); - self::assertEquals('SELECT * FROM user ORDER BY username ASC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithLowercaseOrderBy() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user order by username', 10); - self::assertEquals('SELECT * FROM user order by username OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithDescOrderBy() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10); - self::assertEquals('SELECT * FROM user ORDER BY username DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithMultipleOrderBy() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC, usereamil ASC', 10); - self::assertEquals('SELECT * FROM user ORDER BY username DESC, usereamil ASC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithSubSelect() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result', 10); - self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithSubSelectAndOrder() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC', 10); - self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC', 10); - self::assertEquals('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithSubSelectAndMultipleOrder() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC, uid ASC', 10, 5); - self::assertEquals('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result ORDER BY uname DESC, uid ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id uid, u.name uname) dctrn_result ORDER BY uname DESC, uid ASC', 10, 5); - self::assertEquals('SELECT * FROM (SELECT u.id uid, u.name uname) dctrn_result ORDER BY uname DESC, uid ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - - $sql = $this->platform->modifyLimitQuery('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC, id ASC', 10, 5); - self::assertEquals('SELECT * FROM (SELECT u.id, u.name) dctrn_result ORDER BY name DESC, id ASC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - public function testModifyLimitQueryWithFromColumnNames() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT a.fromFoo, fromBar FROM foo', 10); - self::assertEquals('SELECT a.fromFoo, fromBar FROM foo ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', $sql); - } - - /** - * @group DBAL-927 - */ - public function testModifyLimitQueryWithExtraLongQuery() : void - { - $query = 'SELECT table1.column1, table2.column2, table3.column3, table4.column4, table5.column5, table6.column6, table7.column7, table8.column8 FROM table1, table2, table3, table4, table5, table6, table7, table8 '; - $query .= 'WHERE (table1.column1 = table2.column2) AND (table1.column1 = table3.column3) AND (table1.column1 = table4.column4) AND (table1.column1 = table5.column5) AND (table1.column1 = table6.column6) AND (table1.column1 = table7.column7) AND (table1.column1 = table8.column8) AND (table2.column2 = table3.column3) AND (table2.column2 = table4.column4) AND (table2.column2 = table5.column5) AND (table2.column2 = table6.column6) '; - $query .= 'AND (table2.column2 = table7.column7) AND (table2.column2 = table8.column8) AND (table3.column3 = table4.column4) AND (table3.column3 = table5.column5) AND (table3.column3 = table6.column6) AND (table3.column3 = table7.column7) AND (table3.column3 = table8.column8) AND (table4.column4 = table5.column5) AND (table4.column4 = table6.column6) AND (table4.column4 = table7.column7) AND (table4.column4 = table8.column8) '; - $query .= 'AND (table5.column5 = table6.column6) AND (table5.column5 = table7.column7) AND (table5.column5 = table8.column8) AND (table6.column6 = table7.column7) AND (table6.column6 = table8.column8) AND (table7.column7 = table8.column8)'; - - $sql = $this->platform->modifyLimitQuery($query, 10); - - $expected = 'SELECT table1.column1, table2.column2, table3.column3, table4.column4, table5.column5, table6.column6, table7.column7, table8.column8 FROM table1, table2, table3, table4, table5, table6, table7, table8 '; - $expected .= 'WHERE (table1.column1 = table2.column2) AND (table1.column1 = table3.column3) AND (table1.column1 = table4.column4) AND (table1.column1 = table5.column5) AND (table1.column1 = table6.column6) AND (table1.column1 = table7.column7) AND (table1.column1 = table8.column8) AND (table2.column2 = table3.column3) AND (table2.column2 = table4.column4) AND (table2.column2 = table5.column5) AND (table2.column2 = table6.column6) '; - $expected .= 'AND (table2.column2 = table7.column7) AND (table2.column2 = table8.column8) AND (table3.column3 = table4.column4) AND (table3.column3 = table5.column5) AND (table3.column3 = table6.column6) AND (table3.column3 = table7.column7) AND (table3.column3 = table8.column8) AND (table4.column4 = table5.column5) AND (table4.column4 = table6.column6) AND (table4.column4 = table7.column7) AND (table4.column4 = table8.column8) '; - $expected .= 'AND (table5.column5 = table6.column6) AND (table5.column5 = table7.column7) AND (table5.column5 = table8.column8) AND (table6.column6 = table7.column7) AND (table6.column6 = table8.column8) AND (table7.column7 = table8.column8) '; - $expected .= 'ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - - self::assertEquals($expected, $sql); - } - - /** - * @group DDC-2470 - */ - public function testModifyLimitQueryWithOrderByClause() : void - { - $sql = 'SELECT m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC'; - $expected = 'SELECT m0_.NOMBRE AS NOMBRE0, m0_.FECHAINICIO AS FECHAINICIO1, m0_.FECHAFIN AS FECHAFIN2 FROM MEDICION m0_ WITH (NOLOCK) INNER JOIN ESTUDIO e1_ ON m0_.ESTUDIO_ID = e1_.ID INNER JOIN CLIENTE c2_ ON e1_.CLIENTE_ID = c2_.ID INNER JOIN USUARIO u3_ ON c2_.ID = u3_.CLIENTE_ID WHERE u3_.ID = ? ORDER BY m0_.FECHAINICIO DESC OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY'; - $actual = $this->platform->modifyLimitQuery($sql, 10, 5); - - self::assertEquals($expected, $actual); - } - - /** - * @group DBAL-713 - */ - public function testModifyLimitQueryWithSubSelectInSelectList() : void - { - $sql = $this->platform->modifyLimitQuery( - 'SELECT ' . - 'u.id, ' . - '(u.foo/2) foodiv, ' . - 'CONCAT(u.bar, u.baz) barbaz, ' . - '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . - 'FROM user u ' . - "WHERE u.status = 'disabled'", - 10 - ); - - self::assertEquals( - 'SELECT ' . - 'u.id, ' . - '(u.foo/2) foodiv, ' . - 'CONCAT(u.bar, u.baz) barbaz, ' . - '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . - 'FROM user u ' . - "WHERE u.status = 'disabled' " . - 'ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY', - $sql - ); - } - - /** - * @group DBAL-713 - */ - public function testModifyLimitQueryWithSubSelectInSelectListAndOrderByClause() : void - { - $sql = $this->platform->modifyLimitQuery( - 'SELECT ' . - 'u.id, ' . - '(u.foo/2) foodiv, ' . - 'CONCAT(u.bar, u.baz) barbaz, ' . - '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . - 'FROM user u ' . - "WHERE u.status = 'disabled' " . - 'ORDER BY u.username DESC', - 10, - 5 - ); - - self::assertEquals( - 'SELECT ' . - 'u.id, ' . - '(u.foo/2) foodiv, ' . - 'CONCAT(u.bar, u.baz) barbaz, ' . - '(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count ' . - 'FROM user u ' . - "WHERE u.status = 'disabled' " . - 'ORDER BY u.username DESC ' . - 'OFFSET 5 ROWS FETCH NEXT 10 ROWS ONLY', - $sql - ); - } - - /** - * @group DBAL-834 - */ - public function testModifyLimitQueryWithAggregateFunctionInOrderByClause() : void - { - $sql = $this->platform->modifyLimitQuery( - 'SELECT ' . - 'MAX(heading_id) aliased, ' . - 'code ' . - 'FROM operator_model_operator ' . - 'GROUP BY code ' . - 'ORDER BY MAX(heading_id) DESC', - 1, - 0 - ); - - self::assertEquals( - 'SELECT ' . - 'MAX(heading_id) aliased, ' . - 'code ' . - 'FROM operator_model_operator ' . - 'GROUP BY code ' . - 'ORDER BY MAX(heading_id) DESC ' . - 'OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY', - $sql - ); - } - - public function testModifyLimitQueryWithFromSubquery() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result', 10); - - $expected = 'SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY 1 OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - - self::assertEquals($sql, $expected); - } - - public function testModifyLimitQueryWithFromSubqueryAndOrder() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT DISTINCT id_0, value_1 FROM (SELECT k0_.id AS id_0, k0_.value AS value_1 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY value_1 DESC', 10); - - $expected = 'SELECT DISTINCT id_0, value_1 FROM (SELECT k0_.id AS id_0, k0_.value AS value_1 FROM key_measure k0_ WHERE (k0_.id_zone in(2))) dctrn_result ORDER BY value_1 DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - - self::assertEquals($sql, $expected); - } - - public function testModifyLimitQueryWithComplexOrderByExpression() : void - { - $sql = $this->platform->modifyLimitQuery('SELECT * FROM table ORDER BY (table.x * table.y) DESC', 10); - - $expected = 'SELECT * FROM table ORDER BY (table.x * table.y) DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - - self::assertEquals($sql, $expected); - } - - /** - * @throws DBALException - */ - public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromBaseTable() : void - { - $querySql = 'SELECT DISTINCT id_0, name_1 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY id_0 ASC'; - $alteredSql = 'SELECT DISTINCT id_0, name_1 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY id_0 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 5); - self::assertEquals($alteredSql, $sql); - } - - /** - * @throws DBALException - */ - public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromJoinTable() : void - { - $querySql = 'SELECT DISTINCT id_0, name_1 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY name_1 ASC'; - $alteredSql = 'SELECT DISTINCT id_0, name_1 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY name_1 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 5); - self::assertEquals($alteredSql, $sql); - } - - /** - * @throws DBALException - */ - public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnsFromBothTables() : void - { - $querySql = 'SELECT DISTINCT id_0, name_1, foo_2 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY name_1 ASC, foo_2 DESC'; - $alteredSql = 'SELECT DISTINCT id_0, name_1, foo_2 ' - . 'FROM (' - . 'SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 ' - . 'FROM table_parent t1 ' - . 'LEFT JOIN join_table t2 ON t1.id = t2.table_id' - . ') dctrn_result ' - . 'ORDER BY name_1 ASC, foo_2 DESC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 5); - self::assertEquals($alteredSql, $sql); - } - - public function testModifyLimitSubquerySimple() : void - { - $querySql = 'SELECT DISTINCT id_0 FROM ' - . '(SELECT k0_.id AS id_0, k0_.field AS field_1 ' - . 'FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result'; - $alteredSql = 'SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0, k0_.field AS field_1 ' - . 'FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result ORDER BY 1 OFFSET 0 ROWS FETCH NEXT 20 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 20); - self::assertEquals($alteredSql, $sql); - } - - public function testModifyLimitQueryWithTopNSubQueryWithOrderBy() : void - { - $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC)'; - $expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - self::assertEquals($expectedSql, $sql); - - $querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC'; - $expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY'; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - self::assertEquals($expectedSql, $sql); - } - - public function testModifyLimitQueryWithNewlineBeforeOrderBy() : void - { - $querySql = "SELECT * FROM test\nORDER BY col DESC"; - $expectedSql = "SELECT * FROM test\nORDER BY col DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY"; - $sql = $this->platform->modifyLimitQuery($querySql, 10); - self::assertEquals($expectedSql, $sql); - } -} diff --git a/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php b/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php index a5d27823b38..4760c502149 100644 --- a/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php +++ b/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php @@ -27,15 +27,6 @@ public function testAppendsLockHint($lockMode, string $lockHint) : void self::assertSame($expectedResult, $this->platform->appendLockHint($fromClause, $lockMode)); } - /** - * @group DBAL-2408 - * @dataProvider getModifyLimitQueries - */ - public function testScrubInnerOrderBy(string $query, int $limit, ?int $offset, string $expectedResult) : void - { - self::assertSame($expectedResult, $this->platform->modifyLimitQuery($query, $limit, $offset)); - } - /** * @return mixed[][] */ @@ -52,30 +43,6 @@ public static function getLockHints() : iterable ]; } - /** - * @return mixed[][] - */ - public static function getModifyLimitQueries() : iterable - { - return [ - // Test re-ordered query with correctly-scrubbed ORDER BY clause - [ - 'SELECT id_0, MIN(sclr_2) AS dctrn_minrownum FROM (SELECT c0_.id AS id_0, c0_.title AS title_1, ROW_NUMBER() OVER(ORDER BY c0_.title ASC) AS sclr_2 FROM TestTable c0_ ORDER BY c0_.title ASC) dctrn_result GROUP BY id_0 ORDER BY dctrn_minrownum ASC', - 30, - null, - 'WITH dctrn_cte AS (SELECT TOP 30 id_0, MIN(sclr_2) AS dctrn_minrownum FROM (SELECT c0_.id AS id_0, c0_.title AS title_1, ROW_NUMBER() OVER(ORDER BY c0_.title ASC) AS sclr_2 FROM TestTable c0_) dctrn_result GROUP BY id_0 ORDER BY dctrn_minrownum ASC) SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte) AS doctrine_tbl WHERE doctrine_rownum <= 30 ORDER BY doctrine_rownum ASC', - ], - - // Test re-ordered query with no scrubbed ORDER BY clause - [ - 'SELECT id_0, MIN(sclr_2) AS dctrn_minrownum FROM (SELECT c0_.id AS id_0, c0_.title AS title_1, ROW_NUMBER() OVER(ORDER BY c0_.title ASC) AS sclr_2 FROM TestTable c0_) dctrn_result GROUP BY id_0 ORDER BY dctrn_minrownum ASC', - 30, - null, - 'WITH dctrn_cte AS (SELECT TOP 30 id_0, MIN(sclr_2) AS dctrn_minrownum FROM (SELECT c0_.id AS id_0, c0_.title AS title_1, ROW_NUMBER() OVER(ORDER BY c0_.title ASC) AS sclr_2 FROM TestTable c0_) dctrn_result GROUP BY id_0 ORDER BY dctrn_minrownum ASC) SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte) AS doctrine_tbl WHERE doctrine_rownum <= 30 ORDER BY doctrine_rownum ASC', - ], - ]; - } - public function testGeneratesTypeDeclarationForDateTimeTz() : void { self::assertEquals('DATETIMEOFFSET(6)', $this->platform->getDateTimeTzTypeDeclarationSQL([]));