From 8f8edc0cea68dc33c94f56e61ebd1f56f58af6d0 Mon Sep 17 00:00:00 2001 From: photodude Date: Mon, 12 Mar 2018 21:44:51 -0600 Subject: [PATCH 1/5] Testing of MSSQL on Windows with AppVeyor --- .appveyor.yml | 108 ++++++++++++++++++ .gitattributes | 1 + composer.json | 2 +- .../Driver/Mysqli/MysqliConnectionTest.php | 4 + .../mssql.sql2008r2sp2.sqlsrv.appveyor.xml | 37 ++++++ .../mssql.sql2012sp1.sqlsrv.appveyor.xml | 37 ++++++ .../mssql.sql2017.pdo_sqlsrv.appveyor.xml | 37 ++++++ .../mssql.sql2017.sqlsrv.appveyor.xml | 37 ++++++ 8 files changed, 262 insertions(+), 1 deletion(-) create mode 100644 .appveyor.yml create mode 100644 tests/appveyor/mssql.sql2008r2sp2.sqlsrv.appveyor.xml create mode 100644 tests/appveyor/mssql.sql2012sp1.sqlsrv.appveyor.xml create mode 100644 tests/appveyor/mssql.sql2017.pdo_sqlsrv.appveyor.xml create mode 100644 tests/appveyor/mssql.sql2017.sqlsrv.appveyor.xml diff --git a/.appveyor.yml b/.appveyor.yml new file mode 100644 index 00000000000..ccb9588b6d5 --- /dev/null +++ b/.appveyor.yml @@ -0,0 +1,108 @@ +build: false +platform: + - x64 +#matrix: +# fast_finish: true # kills the build at the first failure +clone_folder: C:\projects\dbal +clone_depth: 1 + +cache: + - C:\ProgramData\chocolatey\bin -> .appveyor.yml + - C:\ProgramData\chocolatey\lib -> .appveyor.yml + - c:\tools\php -> .appveyor.yml + - composer.phar + - '%LOCALAPPDATA%\Composer\files' + #- vendor + +## Build matrix for lowest and highest possible targets +environment: + matrix: + - db: mssql + driver: sqlsrv + db_version: sql2008r2sp2 + php: 7.1 + - db: mssql + driver: sqlsrv + db_version: sql2012sp1 + php: 7.1 + - db: mssql + driver: sqlsrv + db_version: sql2017 + php: 7.1 + - db: mssql + driver: pdo_sqlsrv + db_version: sql2017 + php: 7.1 + +init: + - SET PATH=C:\Program Files\OpenSSL;c:\tools\php;%PATH% + - SET COMPOSER_NO_INTERACTION=1 + - SET ANSICON=121x90 (121x90) + +## Install PHP and composer, and run the appropriate composer command +install: + - ps: | + # Check if installation is cached + if (!(Test-Path c:\tools\php)) { + appveyor-retry cinst --params '""/InstallDir:C:\tools\php""' --ignore-checksums -y php --version ((choco search php --exact --all-versions -r | select-string -pattern $env:php | sort { [version]($_ -split '\|' | select -last 1) } -Descending | Select-Object -first 1) -replace '[php|]','') + # install sqlite + appveyor-retry cinst -y sqlite + Get-ChildItem -Path c:\tools\php + cd c:\tools\php + + # Set PHP environment items that are always needed + copy php.ini-production php.ini + Add-Content php.ini "`n date.timezone=UTC" + Add-Content php.ini "`n extension_dir=ext" + Add-Content php.ini "`n extension=php_openssl.dll" + Add-Content php.ini "`n extension=php_mbstring.dll" + Add-Content php.ini "`n extension=php_fileinfo.dll" + Add-Content php.ini "`n extension=php_pdo_sqlite.dll" + Add-Content php.ini "`n extension=php_sqlite3.dll" + + # If needed get the MSSQL DLL's + if ($env:db -eq "mssql") { + $DLLVersion = "5.2.0rc1" + cd c:\tools\php\ext + $source = "https://windows.php.net/downloads/pecl/releases/sqlsrv/$($DLLVersion)/php_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip" + $destination = "c:\tools\php\ext\php_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip" + Invoke-WebRequest $source -OutFile $destination + 7z x -y php_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip > $null + $source = "https://windows.php.net/downloads/pecl/releases/pdo_sqlsrv/$($DLLVersion)/php_pdo_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip" + $destination = "c:\tools\php\ext\php_pdo_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip" + Invoke-WebRequest $source -OutFile $destination + 7z x -y php_pdo_sqlsrv-$($DLLVersion)-$($env:php)-nts-vc14-x64.zip > $null + Remove-Item c:\tools\php\* -include .zip + cd c:\tools\php + Add-Content php.ini "`nextension=php_sqlsrv.dll" + Add-Content php.ini "`nextension=php_pdo_sqlsrv.dll" + Add-Content php.ini "`n" + } + + cd c:\projects\dbal + + if (!(Test-Path c:\projects\dbal\composer.phar)) { + appveyor-retry appveyor DownloadFile https://getcomposer.org/composer.phar + } + } + # install composer dependencies + - appveyor-retry php composer.phar self-update + - appveyor-retry php composer.phar install --no-progress --profile + +before_test: +# Selectively start the services + - ps: >- + if ($env:db -eq "mssql") { + $instanceName = $env:db_version.ToUpper() + Start-Service "MSSQL`$$instanceName" + } + +test_script: + - cd C:\projects\dbal + - ps: >- + if ($env:db_version) { + vendor\bin\phpunit -c tests\appveyor\%db%.%db_version%.%driver%.appveyor.xml + } + else { + vendor\bin\phpunit -c tests\appveyor\%db%.%driver%.appveyor.xml + } diff --git a/.gitattributes b/.gitattributes index a1cc1016a70..be8ed8213d4 100644 --- a/.gitattributes +++ b/.gitattributes @@ -3,6 +3,7 @@ .gitattributes export-ignore .gitignore export-ignore .gitmodules export-ignore +.appveyor.yml export-ignore .travis.yml export-ignore build.properties export-ignore build.xml export-ignore diff --git a/composer.json b/composer.json index 35e7f3bb741..976c890cf84 100644 --- a/composer.json +++ b/composer.json @@ -42,6 +42,6 @@ } }, "archive": { - "exclude": ["!vendor", "tests", "*phpunit.xml", ".travis.yml", "build.xml", "build.properties", "composer.phar"] + "exclude": ["!vendor", "tests", "*phpunit.xml", ".appveyor.yml", ".travis.yml", "build.xml", "build.properties", "composer.phar"] } } diff --git a/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php b/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php index 166853301c2..eda5e514f5e 100644 --- a/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php +++ b/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php @@ -23,6 +23,10 @@ protected function setUp() parent::setUp(); + if ( ! $this->connectionMock->getDatabasePlatform() instanceof MySqlPlatform) { + $this->markTestSkipped('MySQL only test.'); + } + $this->connectionMock = $this->getMockBuilder(MysqliConnection::class) ->disableOriginalConstructor() ->getMockForAbstractClass(); diff --git a/tests/appveyor/mssql.sql2008r2sp2.sqlsrv.appveyor.xml b/tests/appveyor/mssql.sql2008r2sp2.sqlsrv.appveyor.xml new file mode 100644 index 00000000000..7513b30a44c --- /dev/null +++ b/tests/appveyor/mssql.sql2008r2sp2.sqlsrv.appveyor.xml @@ -0,0 +1,37 @@ + + + + + + + + + + + + + + + + + + + + + + ../Doctrine/Tests/DBAL + + + + + + performance + locking_functional + + + diff --git a/tests/appveyor/mssql.sql2012sp1.sqlsrv.appveyor.xml b/tests/appveyor/mssql.sql2012sp1.sqlsrv.appveyor.xml new file mode 100644 index 00000000000..7457e0018cf --- /dev/null +++ b/tests/appveyor/mssql.sql2012sp1.sqlsrv.appveyor.xml @@ -0,0 +1,37 @@ + + + + + + + + + + + + + + + + + + + + + + ../Doctrine/Tests/DBAL + + + + + + performance + locking_functional + + + diff --git a/tests/appveyor/mssql.sql2017.pdo_sqlsrv.appveyor.xml b/tests/appveyor/mssql.sql2017.pdo_sqlsrv.appveyor.xml new file mode 100644 index 00000000000..bbabc56252a --- /dev/null +++ b/tests/appveyor/mssql.sql2017.pdo_sqlsrv.appveyor.xml @@ -0,0 +1,37 @@ + + + + + + + + + + + + + + + + + + + + + + ../Doctrine/Tests/DBAL + + + + + + performance + locking_functional + + + diff --git a/tests/appveyor/mssql.sql2017.sqlsrv.appveyor.xml b/tests/appveyor/mssql.sql2017.sqlsrv.appveyor.xml new file mode 100644 index 00000000000..9d55e036eac --- /dev/null +++ b/tests/appveyor/mssql.sql2017.sqlsrv.appveyor.xml @@ -0,0 +1,37 @@ + + + + + + + + + + + + + + + + + + + + + + ../Doctrine/Tests/DBAL + + + + + + performance + locking_functional + + + From 193fa28630d3890efcdc71d314851c289ed05994 Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 14 Mar 2018 09:57:10 -0700 Subject: [PATCH 2/5] Fixed MysqliConnectionTest --- .../Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php | 11 +++++------ 1 file changed, 5 insertions(+), 6 deletions(-) diff --git a/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php b/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php index eda5e514f5e..9ee3d26a76e 100644 --- a/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php +++ b/tests/Doctrine/Tests/DBAL/Driver/Mysqli/MysqliConnectionTest.php @@ -4,9 +4,10 @@ use Doctrine\DBAL\Driver\Mysqli\MysqliConnection; use Doctrine\DBAL\Driver\Mysqli\MysqliException; -use Doctrine\Tests\DbalTestCase; +use Doctrine\DBAL\Platforms\MySqlPlatform; +use Doctrine\Tests\DbalFunctionalTestCase; -class MysqliConnectionTest extends DbalTestCase +class MysqliConnectionTest extends DbalFunctionalTestCase { /** * The mysqli driver connection mock under test. @@ -23,8 +24,8 @@ protected function setUp() parent::setUp(); - if ( ! $this->connectionMock->getDatabasePlatform() instanceof MySqlPlatform) { - $this->markTestSkipped('MySQL only test.'); + if (! $this->_conn->getDatabasePlatform() instanceof MySqlPlatform) { + $this->markTestSkipped('MySQL only test.'); } $this->connectionMock = $this->getMockBuilder(MysqliConnection::class) @@ -53,6 +54,4 @@ public function testRestoresErrorHandlerOnException() restore_error_handler(); restore_error_handler(); } - } - From 1ebc1f023ca4610bf82e5c3c88c90bacf08b65cd Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 14 Mar 2018 23:03:09 -0700 Subject: [PATCH 3/5] Fixed handling OFFSET without LIMIT on SQL Server < 2008 --- .../DBAL/Platforms/SQLServerPlatform.php | 27 +++++--- .../AbstractSQLServerPlatformTestCase.php | 66 +++++++++++-------- .../DBAL/Platforms/SQLServerPlatformTest.php | 18 +++-- 3 files changed, 71 insertions(+), 40 deletions(-) diff --git a/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php b/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php index 812bf80a36e..905f6a9fb46 100644 --- a/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php +++ b/lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php @@ -28,6 +28,8 @@ use Doctrine\DBAL\Schema\Table; use Doctrine\DBAL\Schema\TableDiff; use Doctrine\DBAL\Types; +use function implode; +use function sprintf; /** * The SQLServerPlatform provides the behavior, features and SQL dialect of the @@ -1207,19 +1209,29 @@ public function getBooleanTypeDeclarationSQL(array $field) */ protected function doModifyLimitQuery($query, $limit, $offset = null) { - if ($limit === null) { - return $query; + $where = []; + + if ($offset > 0) { + $where[] = sprintf('doctrine_rownum >= %d', $offset + 1); } - $start = $offset + 1; - $end = $offset + $limit; + if ($limit !== null) { + $where[] = sprintf('doctrine_rownum <= %d', $offset + $limit); + $top = sprintf('TOP %d', $offset + $limit); + } else { + $top = 'TOP 9223372036854775807'; + } + + if (empty($where)) { + 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. $selectPattern = '/^(\s*SELECT\s+(?:DISTINCT\s+)?)(.*)$/im'; - $replacePattern = sprintf('$1%s $2', "TOP $end"); + $replacePattern = sprintf('$1%s $2', $top); $query = preg_replace($selectPattern, $replacePattern, $query); if (stristr($query, "ORDER BY")) { @@ -1234,10 +1246,9 @@ protected function doModifyLimitQuery($query, $limit, $offset = null) . "SELECT * FROM (" . "SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte" . ") AS doctrine_tbl " - . "WHERE doctrine_rownum BETWEEN %d AND %d ORDER BY doctrine_rownum ASC", + . 'WHERE %s ORDER BY doctrine_rownum ASC', $query, - $start, - $end + implode(' AND ', $where) ); } diff --git a/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php b/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php index bd2a422a1de..2337b46b5ba 100644 --- a/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php +++ b/tests/Doctrine/Tests/DBAL/Platforms/AbstractSQLServerPlatformTestCase.php @@ -8,11 +8,10 @@ use Doctrine\DBAL\Schema\TableDiff; use Doctrine\DBAL\TransactionIsolationLevel; use Doctrine\DBAL\Types\Type; +use function sprintf; abstract class AbstractSQLServerPlatformTestCase extends AbstractPlatformTestCase { - protected static $selectFromCtePattern = "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 BETWEEN %d AND %d ORDER BY doctrine_rownum ASC"; - public function getGenerateTableSql() { return 'CREATE TABLE test (id INT IDENTITY NOT NULL, test NVARCHAR(255), PRIMARY KEY (id))'; @@ -179,7 +178,7 @@ public function testModifyLimitQuery() $querySql = 'SELECT * FROM user'; $alteredSql = 'SELECT TOP 10 * FROM user'; $sql = $this->_platform->modifyLimitQuery($querySql, 10, 0); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithEmptyOffset() @@ -187,7 +186,7 @@ public function testModifyLimitQueryWithEmptyOffset() $querySql = 'SELECT * FROM user'; $alteredSql = 'SELECT TOP 10 * FROM user'; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithOffset() @@ -200,7 +199,7 @@ public function testModifyLimitQueryWithOffset() $alteredSql = 'SELECT TOP 15 * FROM user ORDER BY username DESC'; $sql = $this->_platform->modifyLimitQuery($querySql, 10, 5); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $sql); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); } public function testModifyLimitQueryWithAscOrderBy() @@ -209,7 +208,7 @@ public function testModifyLimitQueryWithAscOrderBy() $alteredSql = 'SELECT TOP 10 * FROM user ORDER BY username ASC'; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithLowercaseOrderBy() @@ -217,7 +216,7 @@ public function testModifyLimitQueryWithLowercaseOrderBy() $querySql = 'SELECT * FROM user order by username'; $alteredSql = 'SELECT TOP 10 * FROM user order by username'; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithDescOrderBy() @@ -225,7 +224,7 @@ public function testModifyLimitQueryWithDescOrderBy() $querySql = 'SELECT * FROM user ORDER BY username DESC'; $alteredSql = 'SELECT TOP 10 * FROM user ORDER BY username DESC'; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithMultipleOrderBy() @@ -233,7 +232,7 @@ public function testModifyLimitQueryWithMultipleOrderBy() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithSubSelect() @@ -241,7 +240,7 @@ public function testModifyLimitQueryWithSubSelect() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithSubSelectAndOrder() @@ -249,12 +248,12 @@ public function testModifyLimitQueryWithSubSelectAndOrder() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } public function testModifyLimitQueryWithSubSelectAndMultipleOrder() @@ -266,17 +265,17 @@ public function testModifyLimitQueryWithSubSelectAndMultipleOrder() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $sql); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $sql); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $sql); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); } public function testModifyLimitQueryWithFromColumnNames() @@ -284,7 +283,7 @@ public function testModifyLimitQueryWithFromColumnNames() $querySql = 'SELECT a.fromFoo, fromBar FROM foo'; $alteredSql = 'SELECT TOP 10 a.fromFoo, fromBar FROM foo'; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } /** @@ -303,7 +302,7 @@ public function testModifyLimitQueryWithExtraLongQuery() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } /** @@ -319,7 +318,7 @@ public function testModifyLimitQueryWithOrderByClause() $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); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $actual); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $actual); } /** @@ -343,7 +342,7 @@ public function testModifyLimitQueryWithSubSelectInSelectList() "WHERE u.status = 'disabled'"; $sql = $this->_platform->modifyLimitQuery($querySql, 10); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } /** @@ -372,7 +371,7 @@ public function testModifyLimitQueryWithSubSelectInSelectListAndOrderByClause() "WHERE u.status = 'disabled' " . "ORDER BY u.username DESC"; $sql = $this->_platform->modifyLimitQuery($querySql, 10, 5); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 6, 15), $sql); + $this->expectCteWithMinAndMaxRowNums($alteredSql, 6, 15, $sql); } /** @@ -393,7 +392,7 @@ public function testModifyLimitQueryWithAggregateFunctionInOrderByClause() "GROUP BY code " . "ORDER BY MAX(heading_id) DESC"; $sql = $this->_platform->modifyLimitQuery($querySql, 1, 0); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 1), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 1, $sql); } /** @@ -417,10 +416,9 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromBas . ") dctrn_result " . "ORDER BY id_0 ASC"; $sql = $this->_platform->modifyLimitQuery($querySql, 5); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 5), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); } - /** * @throws \Doctrine\DBAL\DBALException */ @@ -442,7 +440,7 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromJoi . ") dctrn_result " . "ORDER BY name_1 ASC"; $sql = $this->_platform->modifyLimitQuery($querySql, 5); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 5), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); } /** @@ -466,7 +464,7 @@ public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnsFromBo . ") dctrn_result " . "ORDER BY name_1 ASC, foo_2 DESC"; $sql = $this->_platform->modifyLimitQuery($querySql, 5); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 5), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 5, $sql); } public function testModifyLimitSubquerySimple() @@ -477,7 +475,7 @@ public function testModifyLimitSubquerySimple() $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"; $sql = $this->_platform->modifyLimitQuery($querySql, 20); - self::assertEquals(sprintf(self::$selectFromCtePattern, $alteredSql, 1, 20), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 20, $sql); } /** @@ -1353,12 +1351,12 @@ public function testModifyLimitQueryWithTopNSubQueryWithOrderBy() $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); - self::assertEquals(sprintf(static::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $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) 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); - self::assertEquals(sprintf(static::$selectFromCtePattern, $alteredSql, 1, 10), $sql); + $this->expectCteWithMaxRowNum($alteredSql, 10, $sql); } /** @@ -1442,4 +1440,16 @@ public function testGetDefaultValueDeclarationSQLForDateType() : void ); } } + + private function expectCteWithMaxRowNum(string $expectedSql, int $expectedMax, string $sql) : 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); + } + + private function expectCteWithMinAndMaxRowNums(string $expectedSql, int $expectedMin, int $expectedMax, string $sql) : 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); + } } diff --git a/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php b/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php index c3f9b6f4023..f8b42f61819 100644 --- a/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php +++ b/tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php @@ -49,12 +49,22 @@ public function getLockHints() public function getModifyLimitQueries() { - return array( + return [ // Test re-ordered query with correctly-scrubbed ORDER BY clause - array('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 BETWEEN 1 AND 30 ORDER BY doctrine_rownum ASC'), + [ + '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 - array('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 BETWEEN 1 AND 30 ORDER BY doctrine_rownum ASC'), - ); + [ + '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', + ], + ]; } } From b1953ea126a448def3d2ab7046c852ff77ab4030 Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 14 Mar 2018 23:17:24 -0700 Subject: [PATCH 4/5] Fixed fetching empty values from a SQL Server statement --- lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvStatement.php | 7 ++++--- 1 file changed, 4 insertions(+), 3 deletions(-) diff --git a/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvStatement.php b/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvStatement.php index 6eaf8f8869a..d2fcc72715e 100644 --- a/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvStatement.php +++ b/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvStatement.php @@ -24,6 +24,7 @@ use Doctrine\DBAL\ParameterType; use IteratorAggregate; use Doctrine\DBAL\Driver\Statement; +use function func_get_args; /** * SQL Server Statement. @@ -348,19 +349,19 @@ public function fetchAll($fetchMode = null, $fetchArgument = null, $ctorArgs = n switch ($fetchMode) { case FetchMode::CUSTOM_OBJECT: - while ($row = call_user_func_array([$this, 'fetch'], func_get_args())) { + while (($row = $this->fetch(...func_get_args())) !== false) { $rows[] = $row; } break; case FetchMode::COLUMN: - while ($row = $this->fetchColumn()) { + while (($row = $this->fetchColumn()) !== false) { $rows[] = $row; } break; default: - while ($row = $this->fetch($fetchMode)) { + while (($row = $this->fetch($fetchMode)) !== false) { $rows[] = $row; } } From cadd79c690e0b49bcd53cf991455607cc375f37e Mon Sep 17 00:00:00 2001 From: Sergei Morozov Date: Wed, 14 Mar 2018 23:34:31 -0700 Subject: [PATCH 5/5] Fixed fetching last inserted ID from a SQL Server connection --- lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvConnection.php | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvConnection.php b/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvConnection.php index 52ad200cf7f..69a91417184 100644 --- a/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvConnection.php +++ b/lib/Doctrine/DBAL/Driver/SQLSrv/SQLSrvConnection.php @@ -136,11 +136,11 @@ public function lastInsertId($name = null) if ($name !== null) { $stmt = $this->prepare('SELECT CONVERT(VARCHAR(MAX), current_value) FROM sys.sequences WHERE name = ?'); $stmt->execute([$name]); - - return $stmt->fetchColumn(); + } else { + $stmt = $this->query('SELECT @@IDENTITY'); } - return $this->lastInsertId->getId(); + return $stmt->fetchColumn(); } /**