From 8fbd32bd2f9d813903cb9dbd6de7e36d5e7927bc Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Mon, 9 Mar 2015 20:44:55 +0400 Subject: [PATCH 1/8] fixed PostgreSQL and Oracle pagination issues Pagination with ordering on 1:m and m:m relations, was not working properly because of selecting the ordered fields in main select statement with distinction (e.g. SELECT DISTINCT e0_.id, p1_.name from ... ) in this case we've received less rows than we've required in query. So I've modified the subquery generation part. In case of PostgreSQL and Oracle added the row_number in the subquery over order by statement, then the main select is grouped by id and selected min of row number, also ordering by rownumber asc, because they are on right order already (e.g. select e0_.id, min(rownum) as rownum from ..... order by rownum). In case of MySQL, the subselect result with ids are in right order so there is no need to select that fields(this fixes the same issue too) In other cases I haven't tested because of that leaved the same. --- .../Pagination/LimitSubqueryOutputWalker.php | 48 ++++++++++++++++--- 1 file changed, 42 insertions(+), 6 deletions(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index 338920b2ef0..e3e312cb99d 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -217,12 +217,48 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, } if (count($orderBy)) { - $sql = sprintf( - 'SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', - implode(', ', array_merge($sqlIdentifier, $sqlOrderColumns)), - $innerSql, - implode(', ', $orderBy) - ); + + // http://www.doctrine-project.org/jira/browse/DDC-1958 + if ($this->platform->getName() == 'postgresql' || $this->platform->getName() == 'oracle') { + if (preg_match('/SELECT (.*?) FROM /i', $innerSql, $regs)) { + $selectedParts = explode(",", $regs[1]); + } + $globalOrderByStmt = SqlWalker::walkOrderByClause($AST->orderByClause); + + /* + * 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("row_number() OVER(%s) as rownum ", $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 + $sql = sprintf( + 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', + implode(', ', array_merge($sqlIdentifier, ['min(rownum) as minrow'])), + $innerSql, implode(',', $sqlIdentifier), + 'minrow asc'); + } else { + + /* + * 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. + */ + if($this->platform->getName() == 'mysql'){ + $selectFields = array_merge($sqlIdentifier); + } else { + $selectFields = array_merge($sqlIdentifier, $sqlOrderColumns); + } + $sql = sprintf( + 'SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', + implode(', ', $selectFields), + $innerSql, + implode(', ', $orderBy) + ); + } } return $sql; From b68c93cf68840c2d1fe53cc05f417baa9c9633cf Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 10 Mar 2015 00:45:00 +0400 Subject: [PATCH 2/8] Fixed missing spaces around if on line 250 --- lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index e3e312cb99d..edec2ae51d6 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -247,7 +247,7 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, * which are participated in order by statement, arent selected in * main select statement. */ - if($this->platform->getName() == 'mysql'){ + if ($this->platform->getName() == 'mysql') { $selectFields = array_merge($sqlIdentifier); } else { $selectFields = array_merge($sqlIdentifier, $sqlOrderColumns); From 827d53ff13a4e9d77ffd66e32632676b7ccb5744 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 10 Mar 2015 02:16:52 +0400 Subject: [PATCH 3/8] fixed array declaration syntax for <5.4 versions --- lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index edec2ae51d6..e9b96e06406 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -237,7 +237,7 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, // Grouping by primary key and min(rownumber) for correct result $sql = sprintf( 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', - implode(', ', array_merge($sqlIdentifier, ['min(rownum) as minrow'])), + implode(', ', array_merge($sqlIdentifier, array('min(rownum) as minrow'))), $innerSql, implode(',', $sqlIdentifier), 'minrow asc'); } else { From 43d7ef7d59fb69a0d407895a90c3df41bc961296 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 10 Mar 2015 06:47:42 +0400 Subject: [PATCH 4/8] updated testcases relaying on changes --- .../Tools/Pagination/LimitSubqueryOutputWalker.php | 11 ++++++++--- .../Pagination/LimitSubqueryOutputWalkerTest.php | 14 +++++++------- 2 files changed, 15 insertions(+), 10 deletions(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index e9b96e06406..8374d6f1360 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -225,11 +225,16 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, } $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("row_number() OVER(%s) as rownum ", $globalOrderByStmt); + $selectedParts[] = sprintf($innerRowNumberSelectPart, $globalOrderByStmt); $selectClause = implode(',', $selectedParts); $innerSql = preg_replace("/^\s*select .+ from (.*)$/im", "SELECT {$selectClause} FROM $1", $innerSql); @@ -237,9 +242,9 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, // Grouping by primary key and min(rownumber) for correct result $sql = sprintf( 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', - implode(', ', array_merge($sqlIdentifier, array('min(rownum) as minrow'))), + implode(', ', array_merge($sqlIdentifier, array($mainRowNumberSelectPart))), $innerSql, implode(',', $sqlIdentifier), - 'minrow asc'); + $mainRowNumberOrderPart); } else { /* diff --git a/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php b/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php index e8d7910b34d..1a365bfc508 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 as", $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) 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() ); From fca3767f0f7abe66d0137544f17fc50d45baf5f0 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 10 Mar 2015 07:14:34 +0400 Subject: [PATCH 5/8] Tests --- .../Pagination/LimitSubqueryOutputWalkerTest.php | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php b/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php index 1a365bfc508..d5c727edf80 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 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() + "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 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", + "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 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", + "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 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", + "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 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 as", $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); @@ -157,7 +157,7 @@ public function testLimitSubqueryWithMixedSortOracle() $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker'); $this->assertEquals( - "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, u1_.id DESC) dctrn_result GROUP BY ID_1 ORDER BY MINROWNUM 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, 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() ); From a09f1cbd7242c9f6d48d6552d73cb238f5d23823 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 10 Mar 2015 15:29:32 +0400 Subject: [PATCH 6/8] lexer check 'as' > 'AS' --- .../Tools/Pagination/LimitSubqueryOutputWalker.php | 2 +- .../Pagination/LimitSubqueryOutputWalkerTest.php | 14 +++++++------- 2 files changed, 8 insertions(+), 8 deletions(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index 8374d6f1360..c67ebcd3d2a 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -225,7 +225,7 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, } $globalOrderByStmt = SqlWalker::walkOrderByClause($AST->orderByClause); - $innerRowNumberSelectPart = ' ROW_NUMBER() OVER(%s) as ROWNUM'; + $innerRowNumberSelectPart = ' ROW_NUMBER() OVER(%s) AS ROWNUM'; $mainRowNumberSelectPart = 'MIN(ROWNUM) AS MINROWNUM'; $mainRowNumberOrderPart = 'MINROWNUM ASC'; diff --git a/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php b/tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php index d5c727edf80..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 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() + "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 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", + "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 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", + "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 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", + "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 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() + "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 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", + "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 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", + "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() ); From dfc1264963e4c2bc85936e5680915cff38639a59 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 17 Mar 2015 04:15:18 +0400 Subject: [PATCH 7/8] Syntax fixing as suggested --- .../Pagination/LimitSubqueryOutputWalker.php | 88 +++++++++---------- 1 file changed, 44 insertions(+), 44 deletions(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index c67ebcd3d2a..b39352c8964 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -217,55 +217,55 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, } if (count($orderBy)) { - // http://www.doctrine-project.org/jira/browse/DDC-1958 - if ($this->platform->getName() == 'postgresql' || $this->platform->getName() == 'oracle') { - 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 - $sql = sprintf( - 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', - implode(', ', array_merge($sqlIdentifier, array($mainRowNumberSelectPart))), - $innerSql, implode(',', $sqlIdentifier), - $mainRowNumberOrderPart); - } else { - + 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. - */ - if ($this->platform->getName() == 'mysql') { - $selectFields = array_merge($sqlIdentifier); - } else { - $selectFields = array_merge($sqlIdentifier, $sqlOrderColumns); - } - $sql = sprintf( - 'SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', - implode(', ', $selectFields), - $innerSql, - implode(', ', $orderBy) - ); + * 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(', ', $selectFields), $innerSql, implode(', ', $orderBy)); } 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); + } } From c674a156169d062695a51f83d34a961a128ffe41 Mon Sep 17 00:00:00 2001 From: Vahe Shadunts Date: Tue, 17 Mar 2015 15:23:19 +0400 Subject: [PATCH 8/8] Stylistic changes --- .../Pagination/LimitSubqueryOutputWalker.php | 15 +++++++++++++-- 1 file changed, 13 insertions(+), 2 deletions(-) diff --git a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php index b39352c8964..5cacf9a2ef8 100644 --- a/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php +++ b/lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php @@ -233,7 +233,12 @@ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, $selectFields = array_merge($sqlIdentifier, $sqlOrderColumns); } - return sprintf('SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', implode(', ', $selectFields), $innerSql, implode(', ', $orderBy)); + return sprintf( + 'SELECT DISTINCT %s FROM (%s) dctrn_result ORDER BY %s', + implode(', ', $selectFields), + $innerSql, + implode(', ', $orderBy) + ); } return $sql; @@ -266,6 +271,12 @@ private function generateLimitQueryWithRowNumber(SelectStatement $AST, array $sq $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); + return sprintf( + 'SELECT %s FROM (%s) dctrn_result GROUP BY %s ORDER BY %s', + implode(', ', array_merge($sqlIdentifier, array($mainRowNumberSelectPart))), + $innerSql, + implode(',', $sqlIdentifier), + $mainRowNumberOrderPart + ); } }