Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP

Loading…

Oracle Pagination bug when ordering is present #646

Merged
merged 3 commits into from

5 participants

@doctrinebot
Collaborator

Hello,

thank you for creating this pull request. I have automatically opened an issue
on our Jira Bug Tracker for you. See the issue link:

http://www.doctrine-project.org/jira/browse/DDC-2396

We use Jira to track the state of pull requests and the versions they got
included in.

@guilhermeblanco

@raykolbe can you add a test for this, please?

@mvrhov

This is the bug I've encountered about a year ago and I was really surprised then that this didn't popp up more frequently. IMO this shows that people are still to centered on MySQL which completely disregards some parts of the SQL standards.

@raykolbe

@guilhermeblanco I'll take a swing at it.

@mvrhov I've been using Doctrine2 w/Oracle for about a couple of years now w/no major issues. I think Oracle gets left behind sometimes, as I'm sure MSSQL does, because they are used less frequently in the PHP world. I also noticed that the Travis builds don't build against Oracle. Perhaps I'm mistaken here?

@raykolbe

@guilhermeblanco I added the tests but I'm not sure why the commit is not showing up in this PR.

@guilhermeblanco

@raykolbe that's perfect.
We're negotiating a possible way to have Oracle and SQL Server tests running somehow in a VM.
Until that, we basically implemented the original set of features and we rely on spec and users to get it working correctly.

@guilhermeblanco guilhermeblanco merged commit e835175 into doctrine:master

1 check passed

Details default The Travis build passed
@beberlei
Owner

I can't seem to get this merged back, because suddently the OrderByItem doesn't have expressions anymore in every instance, leading to notices. This will be a 2.4 only fix, i don't want to mess with this too much

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
This page is out of date. Refresh to see the latest.
View
14 lib/Doctrine/ORM/Tools/Pagination/LimitSubqueryOutputWalker.php
@@ -16,6 +16,7 @@
use Doctrine\ORM\Query\SqlWalker;
use Doctrine\ORM\Query\AST\SelectStatement;
use Doctrine\DBAL\Platforms\PostgreSqlPlatform;
+use Doctrine\DBAL\Platforms\OraclePlatform;
/**
* Wraps the query in order to select root entity IDs for pagination.
@@ -137,13 +138,14 @@ public function walkSelectStatement(SelectStatement $AST)
));
}
- // Build the counter query.
+ // Build the counter query
$sql = sprintf('SELECT DISTINCT %s FROM (%s) dctrn_result',
implode(', ', $sqlIdentifier), $innerSql);
- if ($this->platform instanceof PostgreSqlPlatform) {
+ if ($this->platform instanceof PostgreSqlPlatform ||
+ $this->platform instanceof OraclePlatform) {
//http://www.doctrine-project.org/jira/browse/DDC-1958
- $this->getPostgresqlSql($AST, $sqlIdentifier, $innerSql, $sql);
+ $this->preserveSqlOrdering($AST, $sqlIdentifier, $innerSql, $sql);
}
// Apply the limit and offset.
@@ -161,9 +163,9 @@ public function walkSelectStatement(SelectStatement $AST)
return $sql;
}
-
+
/**
- * Generates new SQL for postgresql if necessary.
+ * Generates new SQL for Postgresql or Oracle if necessary.
*
* @param SelectStatement $AST
* @param array $sqlIdentifier
@@ -172,7 +174,7 @@ public function walkSelectStatement(SelectStatement $AST)
*
* @return void
*/
- public function getPostgresqlSql(SelectStatement $AST, array $sqlIdentifier, $innerSql, &$sql)
+ public function preserveSqlOrdering(SelectStatement $AST, array $sqlIdentifier, $innerSql, &$sql)
{
// For every order by, find out the SQL alias by inspecting the ResultSetMapping.
$sqlOrderColumns = array();
View
76 tests/Doctrine/Tests/ORM/Tools/Pagination/LimitSubqueryOutputWalkerTest.php
@@ -83,6 +83,82 @@ public function testLimitSubqueryPg()
$this->entityManager->getConnection()->setDatabasePlatform($odp);
}
+
+ public function testLimitSubqueryWithSortOracle()
+ {
+ $odp = $this->entityManager->getConnection()->getDatabasePlatform();
+ $this->entityManager->getConnection()->setDatabasePlatform(new \Doctrine\DBAL\Platforms\OraclePlatform);
+
+ $query = $this->entityManager->createQuery(
+ 'SELECT p, c, a FROM Doctrine\Tests\ORM\Tools\Pagination\MyBlogPost p JOIN p.category c JOIN p.author a ORDER BY p.title');
+ $query->expireQueryCache(true);
+ $limitQuery = clone $query;
+ $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker');
+
+ $this->assertEquals(
+ "SELECT DISTINCT ID0, TITLE1 FROM (SELECT m0_.id AS ID0, m0_.title AS TITLE1, c1_.id AS ID2, a2_.id AS ID3, a2_.name AS NAME4, m0_.author_id AS AUTHOR_ID5, m0_.category_id AS CATEGORY_ID6 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 TITLE1 ASC", $limitQuery->getSql()
+ );
+
+ $this->entityManager->getConnection()->setDatabasePlatform($odp);
+ }
+
+ public function testLimitSubqueryWithScalarSortOracle()
+ {
+ $odp = $this->entityManager->getConnection()->getDatabasePlatform();
+ $this->entityManager->getConnection()->setDatabasePlatform(new \Doctrine\DBAL\Platforms\OraclePlatform);
+
+ $query = $this->entityManager->createQuery(
+ 'SELECT u, g, COUNT(g.id) AS g_quantity FROM Doctrine\Tests\ORM\Tools\Pagination\User u JOIN u.groups g ORDER BY g_quantity'
+ );
+ $query->expireQueryCache(true);
+ $limitQuery = clone $query;
+ $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker');
+
+ $this->assertEquals(
+ "SELECT DISTINCT ID1, SCLR0 FROM (SELECT COUNT(g0_.id) AS SCLR0, u1_.id AS ID1, g0_.id AS ID2 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 SCLR0 ASC) dctrn_result ORDER BY SCLR0 ASC",
+ $limitQuery->getSql()
+ );
+
+ $this->entityManager->getConnection()->setDatabasePlatform($odp);
+ }
+
+ public function testLimitSubqueryWithMixedSortOracle()
+ {
+ $odp = $this->entityManager->getConnection()->getDatabasePlatform();
+ $this->entityManager->getConnection()->setDatabasePlatform(new \Doctrine\DBAL\Platforms\OraclePlatform);
+
+ $query = $this->entityManager->createQuery(
+ 'SELECT u, g, COUNT(g.id) AS g_quantity FROM Doctrine\Tests\ORM\Tools\Pagination\User u JOIN u.groups g ORDER BY g_quantity, u.id DESC'
+ );
+ $query->expireQueryCache(true);
+ $limitQuery = clone $query;
+ $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker');
+
+ $this->assertEquals(
+ "SELECT DISTINCT ID1, SCLR0 FROM (SELECT COUNT(g0_.id) AS SCLR0, u1_.id AS ID1, g0_.id AS ID2 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 SCLR0 ASC, u1_.id DESC) dctrn_result ORDER BY SCLR0 ASC, ID1 DESC",
+ $limitQuery->getSql()
+ );
+
+ $this->entityManager->getConnection()->setDatabasePlatform($odp);
+ }
+
+ public function testLimitSubqueryOracle()
+ {
+ $odp = $this->entityManager->getConnection()->getDatabasePlatform();
+ $this->entityManager->getConnection()->setDatabasePlatform(new \Doctrine\DBAL\Platforms\OraclePlatform);
+
+ $query = $this->entityManager->createQuery(
+ 'SELECT p, c, a FROM Doctrine\Tests\ORM\Tools\Pagination\MyBlogPost p JOIN p.category c JOIN p.author a');
+ $query->expireQueryCache(true);
+ $limitQuery = clone $query;
+ $limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubqueryOutputWalker');
+
+ $this->assertEquals(
+ "SELECT DISTINCT ID0 FROM (SELECT m0_.id AS ID0, m0_.title AS TITLE1, c1_.id AS ID2, a2_.id AS ID3, a2_.name AS NAME4, m0_.author_id AS AUTHOR_ID5, m0_.category_id AS CATEGORY_ID6 FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id) dctrn_result", $limitQuery->getSql()
+ );
+
+ $this->entityManager->getConnection()->setDatabasePlatform($odp);
+ }
public function testCountQuery_MixedResultsWithName()
{
Something went wrong with that request. Please try again.