diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index 338920b2ef0..5cacf9a2ef8 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -217,9 +217,25 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, } if (count($orderBy)) { - $sql = sprintf( + // http://www.doctrine-project.org/jira/browse/DDC-1958 + if ($this->platform instanceof \Doctrine\DBAL\Platforms\PostgreSqlPlatform || $this->platform instanceof \Doctrine\DBAL\Platforms\OraclePlatform) { + return $this->generateLimitQueryWithRowNumber($AST, $sqlIdentifier, $innerSql); + } + elseif ($this->platform instanceof \Doctrine\DBAL\Platforms\MySqlPlatform) { + /* + * MySQL does'nt reset the ordering of subselect even when the fields + * which are participated in order by statement, arent selected in + * main select statement. + */ + $selectFields = $sqlIdentifier; + } + else { + $selectFields = array_merge($sqlIdentifier, $sqlOrderColumns); + } + + return sprintf( 'SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', - implode(', ', array_merge($sqlIdentifier, $sqlOrderColumns)), + implode(', ', $selectFields), $innerSql, implode(', ', $orderBy) ); @@ -227,4 +243,40 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, return $sql; } + + /** + * @param SelectStatement $AST + * @param array $sqlIdentifier + * @param string $innerSql + * + * @return string + */ + private function generateLimitQueryWithRowNumber(SelectStatement $AST, array $sqlIdentifier, $innerSql) { + if (preg_match('/SELECT (.*?) FROM /i', $innerSql, $regs)) { + $selectedParts = explode(",", $regs[1]); + } + $globalOrderByStmt = SqlWalker::walkOrderByClause($AST->orderByClause); + + $innerRowNumberSelectPart = ' ROW_NUMBER() OVER(%s) AS ROWNUM'; + $mainRowNumberSelectPart = 'MIN(ROWNUM) AS MINROWNUM'; + $mainRowNumberOrderPart = 'MINROWNUM ASC'; + + /* + * Adding row_number in select statement, instead of selecting all fields in order clause + * being away from the DISTINCTION leaks, (e.g. 1-a, a 1-b) + */ + $selectedParts[] = sprintf($innerRowNumberSelectPart, $globalOrderByStmt); + + $selectClause = implode(',', $selectedParts); + $innerSql = preg_replace("/^\s*select .+ from (.*)$/im", "SELECT {$selectClause} FROM $1", $innerSql); + + // Grouping by primary key and min(rownumber) for correct result + return sprintf( + 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', + implode(', ', array_merge($sqlIdentifier, array($mainRowNumberSelectPart))), + $innerSql, + implode(',', $sqlIdentifier), + $mainRowNumberOrderPart + ); + } } diff --git a/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php b/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php index e8d7910b34d..73f79f74df1 100644 --- a/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php +++ b/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php @@ -33,7 +33,7 @@ public function testLimitSubqueryWithSortPg() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT id_0, title_1 FROM (SELECT m0_.id AS id_0, m0_.title AS title_1, c1_.id AS id_2, a2_.id AS id_3, a2_.name AS name_4, m0_.author_id AS author_id_5, m0_.category_id AS category_id_6 FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id ORDER BY m0_.title ASC) dctrn_result ORDER BY title_1 ASC", $limitQuery->getSql() + "SELECT id_0, MIN(ROWNUM) AS MINROWNUM FROM (SELECT m0_.id AS id_0, m0_.title AS title_1, c1_.id AS id_2, a2_.id AS id_3, a2_.name AS name_4, m0_.author_id AS author_id_5, m0_.category_id AS category_id_6, ROW_NUMBER() OVER( ORDER BY m0_.title ASC) AS ROWNUM FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id ORDER BY m0_.title ASC) dctrn_result GROUP BY id_0 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); $this->entityManager->getConnection()->setDatabasePlatform($odp); @@ -51,7 +51,7 @@ public function testLimitSubqueryWithScalarSortPg() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT id_1, sclr_0 FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2 FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC) dctrn_result ORDER BY sclr_0 ASC", + "SELECT id_1, MIN(ROWNUM) AS MINROWNUM FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2, ROW_NUMBER() OVER( ORDER BY sclr_0 ASC) AS ROWNUM FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC) dctrn_result GROUP BY id_1 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); @@ -70,7 +70,7 @@ public function testLimitSubqueryWithMixedSortPg() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT id_1, sclr_0 FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2 FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC, u1_.id DESC) dctrn_result ORDER BY sclr_0 ASC, id_1 DESC", + "SELECT id_1, MIN(ROWNUM) AS MINROWNUM FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2, ROW_NUMBER() OVER( ORDER BY sclr_0 ASC, u1_.id DESC) AS ROWNUM FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC, u1_.id DESC) dctrn_result GROUP BY id_1 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); @@ -89,7 +89,7 @@ public function testLimitSubqueryWithHiddenScalarSortPg() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT id_1, sclr_0 FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2 FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC, u1_.id DESC) dctrn_result ORDER BY sclr_0 ASC, id_1 DESC", + "SELECT id_1, MIN(ROWNUM) AS MINROWNUM FROM (SELECT COUNT(g0_.id) AS sclr_0, u1_.id AS id_1, g0_.id AS id_2, ROW_NUMBER() OVER( ORDER BY sclr_0 ASC, u1_.id DESC) AS ROWNUM FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY sclr_0 ASC, u1_.id DESC) dctrn_result GROUP BY id_1 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); @@ -118,7 +118,7 @@ public function testLimitSubqueryWithSortOracle() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT ID_0, TITLE_1 FROM (SELECT m0_.id AS ID_0, m0_.title AS TITLE_1, c1_.id AS ID_2, a2_.id AS ID_3, a2_.name AS NAME_4, m0_.author_id AS AUTHOR_ID_5, m0_.category_id AS CATEGORY_ID_6 FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id ORDER BY m0_.title ASC) dctrn_result ORDER BY TITLE_1 ASC", $limitQuery->getSql() + "SELECT ID_0, MIN(ROWNUM) AS MINROWNUM FROM (SELECT m0_.id AS ID_0, m0_.title AS TITLE_1, c1_.id AS ID_2, a2_.id AS ID_3, a2_.name AS NAME_4, m0_.author_id AS AUTHOR_ID_5, m0_.category_id AS CATEGORY_ID_6, ROW_NUMBER() OVER( ORDER BY m0_.title ASC) AS ROWNUM FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id ORDER BY m0_.title ASC) dctrn_result GROUP BY ID_0 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); $this->entityManager->getConnection()->setDatabasePlatform($odp); @@ -137,7 +137,7 @@ public function testLimitSubqueryWithScalarSortOracle() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT ID_1, SCLR_0 FROM (SELECT COUNT(g0_.id) AS SCLR_0, u1_.id AS ID_1, g0_.id AS ID_2 FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY SCLR_0 ASC) dctrn_result ORDER BY SCLR_0 ASC", + "SELECT ID_1, MIN(ROWNUM) AS MINROWNUM FROM (SELECT COUNT(g0_.id) AS SCLR_0, u1_.id AS ID_1, g0_.id AS ID_2, ROW_NUMBER() OVER( ORDER BY SCLR_0 ASC) AS ROWNUM FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY SCLR_0 ASC) dctrn_result GROUP BY ID_1 ORDER BY MINROWNUM ASC", $limitQuery->getSql() ); @@ -157,7 +157,7 @@ public function testLimitSubqueryWithMixedSortOracle() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "SELECT DISTINCT ID_1, SCLR_0 FROM (SELECT COUNT(g0_.id) AS SCLR_0, u1_.id AS ID_1, g0_.id AS ID_2 FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY SCLR_0 ASC, u1_.id DESC) dctrn_result ORDER BY SCLR_0 ASC, ID_1 DESC", + "SELECT ID_1, MIN(ROWNUM) AS MINROWNUM FROM (SELECT COUNT(g0_.id) AS SCLR_0, u1_.id AS ID_1, g0_.id AS ID_2, ROW_NUMBER() OVER( ORDER BY SCLR_0 ASC, u1_.id DESC) AS ROWNUM FROM User u1_ INNER JOIN user_group u2_ ON u1_.id = u2_.user_id INNER JOIN groups g0_ ON g0_.id = u2_.group_id ORDER BY SCLR_0 ASC, u1_.id DESC) dctrn_result GROUP BY ID_1 ORDER BY MINROWNUM ASC", $limitQuery->getSql() );