1
0
mirror of synced 2025-02-20 06:03:15 +03:00

Pagination using SQL walkers

A CountSqlWalker and LimitSubquerySqlWalker have been implemented. By
default the Paginator will use these SQL walkers. When a query already
uses custom SQL walkers, the Paginator will fall back to the existing
TreeWalker implementations. Improvements:

* Support for more complex DQL queries using named mixed results with
  GROUP BY and HAVING. For example:

  SELECT g, u, COUNT(u.id) AS userCount
      FROM Entity\Group g LEFT JOIN g.users u
      GROUP BY g.id
      HAVING userCount > 0

* Support for entities with composite primary keys in the CountSqlWalker
  and LimitSubquerySqlWalker. Only the WhereInWalker still needs to be
  updated for full composite primary key support. But someone smarter
  than me needs to look at that and figure out how to build a WHERE IN
  query that can select rows based on multiple columns.
This commit is contained in:
Sander Marechal 2012-03-06 16:24:44 +01:00
parent f6a61b133e
commit edd5d14b06
6 changed files with 458 additions and 4 deletions

View File

@ -0,0 +1,120 @@
<?php
/**
* Doctrine ORM
*
* LICENSE
*
* This source file is subject to the new BSD license that is bundled
* with this package in the file LICENSE.txt.
* If you did not receive a copy of the license and are unable to
* obtain it through the world-wide-web, please send an email
* to kontakt@beberlei.de so I can send you a copy immediately.
*/
namespace Doctrine\ORM\Tools\Pagination;
use Doctrine\ORM\Query\SqlWalker,
Doctrine\ORM\Query\AST\SelectStatement;
/**
* Wrap the query in order to accurately count the root objects
*
* Given a DQL like `SELECT u FROM User u` it will generate an SQL query like:
* SELECT COUNT(*) (SELECT DISTINCT <id> FROM (<original SQL>))
*
* Works with composite keys but cannot deal with queries that have multiple
* root entities (e.g. `SELECT f, b from Foo, Bar`)
*
* @author Sander Marechal <s.marechal@jejik.com>
*/
class CountSqlWalker extends SqlWalker
{
/**
* @var Doctrine\DBAL\Platforms\AbstractPlatform
*/
private $platform;
/**
* @var Doctrine\ORM\Query\ResultSetMapping
*/
private $rsm;
/**
* @var array
*/
private $queryComponents;
/**
* Constructor. Stores various parameters that are otherwise unavailable
* because Doctrine\ORM\Query\SqlWalker keeps everything private without
* accessors.
*
* @param Doctrine\ORM\Query $query
* @param Doctrine\ORM\Query\ParserResult $parserResult
* @param array $queryComponents
*/
public function __construct($query, $parserResult, array $queryComponents)
{
$this->platform = $query->getEntityManager()->getConnection()->getDatabasePlatform();
$this->rsm = $parserResult->getResultSetMapping();
$this->queryComponents = $queryComponents;
parent::__construct($query, $parserResult, $queryComponents);
}
/**
* Walks down a SelectStatement AST node, wrapping it in a COUNT (SELECT DISTINCT)
*
* Note that the ORDER BY clause is not removed. Many SQL implementations (e.g. MySQL)
* are able to cache subqueries. By keeping the ORDER BY clause intact, the limitSubQuery
* that will most likely be executed next can be read from the native SQL cache.
*
* @param SelectStatement $AST
* @return string
*/
public function walkSelectStatement(SelectStatement $AST)
{
$sql = parent::walkSelectStatement($AST);
// Find out the SQL alias of the identifier column of the root entity
// It may be possible to make this work with multiple root entities but that
// would probably require issuing multiple queries or doing a UNION SELECT
// so for now, It's not supported.
// Get the root entity and alias from the AST fromClause
$from = $AST->fromClause->identificationVariableDeclarations;
if (count($from) > 1) {
throw new \RuntimeException("Cannot count query which selects two FROM components, cannot make distinction");
}
$rootClass = $from[0]->rangeVariableDeclaration->abstractSchemaName;
$rootAlias = $from[0]->rangeVariableDeclaration->aliasIdentificationVariable;
// Get the identity properties from the metadata
$rootIdentifier = $this->queryComponents[$rootAlias]['metadata']->identifier;
// For every identifier, find out the SQL alias by combing through the ResultSetMapping
$sqlIdentifier = array();
foreach ($rootIdentifier as $property) {
foreach (array_keys($this->rsm->fieldMappings, $property) as $alias) {
if ($this->rsm->columnOwnerMap[$alias] == $rootAlias) {
$sqlIdentifier[$property] = $alias;
}
}
}
if (count($rootIdentifier) != count($sqlIdentifier)) {
throw new \RuntimeException(sprintf(
'Not all identifier properties can be found in the ResultSetMapping: %s',
implode(', ', array_diff($rootIdentifier, array_keys($sqlIdentifier)))
));
}
// Build the counter query
return sprintf('SELECT %s AS _dctrn_count FROM (SELECT DISTINCT %s FROM (%s) AS _dctrn_result) AS _dctrn_table',
$this->platform->getCountExpression('*'),
implode(', ', $sqlIdentifier),
$sql
);
}
}

View File

@ -0,0 +1,144 @@
<?php
/**
* Doctrine ORM
*
* LICENSE
*
* This source file is subject to the new BSD license that is bundled
* with this package in the file LICENSE.txt.
* If you did not receive a copy of the license and are unable to
* obtain it through the world-wide-web, please send an email
* to kontakt@beberlei.de so I can send you a copy immediately.
*/
namespace Doctrine\ORM\Tools\Pagination;
use Doctrine\ORM\Query\SqlWalker,
Doctrine\ORM\Query\AST\SelectStatement;
/**
* Wrap the query in order to select root entity IDs for pagination
*
* Given a DQL like `SELECT u FROM User u` it will generate an SQL query like:
* SELECT DISTINCT <id> FROM (<original SQL>) LIMIT x OFFSET y
*
* Works with composite keys but cannot deal with queries that have multiple
* root entities (e.g. `SELECT f, b from Foo, Bar`)
*
* @author Sander Marechal <s.marechal@jejik.com>
*/
class LimitSubquerySqlWalker extends SqlWalker
{
/**
* @var Doctrine\DBAL\Platforms\AbstractPlatform
*/
private $platform;
/**
* @var Doctrine\ORM\Query\ResultSetMapping
*/
private $rsm;
/**
* @var array
*/
private $queryComponents;
/**
* @var int
*/
private $firstResult;
/**
* @var int
*/
private $maxResults;
/**
* Constructor. Stores various parameters that are otherwise unavailable
* because Doctrine\ORM\Query\SqlWalker keeps everything private without
* accessors.
*
* @param Doctrine\ORM\Query $query
* @param Doctrine\ORM\Query\ParserResult $parserResult
* @param array $queryComponents
*/
public function __construct($query, $parserResult, array $queryComponents)
{
$this->platform = $query->getEntityManager()->getConnection()->getDatabasePlatform();
$this->rsm = $parserResult->getResultSetMapping();
$this->queryComponents = $queryComponents;
// Reset limit and offset
$this->firstResult = $query->getFirstResult();
$this->maxResults = $query->getMaxResults();
$query->setFirstResult(null)->setMaxResults(null);
parent::__construct($query, $parserResult, $queryComponents);
}
/**
* Walks down a SelectStatement AST node, wrapping it in a SELECT DISTINCT
*
* @param SelectStatement $AST
* @return string
*/
public function walkSelectStatement(SelectStatement $AST)
{
$sql = parent::walkSelectStatement($AST);
// Find out the SQL alias of the identifier column of the root entity
// It may be possible to make this work with multiple root entities but that
// would probably require issuing multiple queries or doing a UNION SELECT
// so for now, It's not supported.
// Get the root entity and alias from the AST fromClause
$from = $AST->fromClause->identificationVariableDeclarations;
if (count($from) !== 1) {
throw new \RuntimeException("Cannot count query which selects two FROM components, cannot make distinction");
}
$rootClass = $from[0]->rangeVariableDeclaration->abstractSchemaName;
$rootAlias = $from[0]->rangeVariableDeclaration->aliasIdentificationVariable;
// Get the identity properties from the metadata
$metadata = $this->queryComponents[$rootAlias]['metadata'];
$rootIdentifier = $metadata->identifier;
// For every identifier, find out the SQL alias by combing through the ResultSetMapping
$sqlIdentifier = array();
foreach ($rootIdentifier as $property) {
foreach (array_keys($this->rsm->fieldMappings, $property) as $alias) {
if ($this->rsm->columnOwnerMap[$alias] == $rootAlias) {
$sqlIdentifier[$property] = $alias;
}
}
}
if (count($rootIdentifier) != count($sqlIdentifier)) {
throw new \RuntimeException(sprintf(
'Not all identifier properties can be found in the ResultSetMapping: %s',
implode(', ', array_diff($rootIdentifier, array_keys($sqlIdentifier)))
));
}
// Build the counter query
$sql = sprintf('SELECT DISTINCT %s FROM (%s) AS _dctrn_result',
implode(', ', $sqlIdentifier), $sql);
// Apply the limit and offset
$sql = $this->platform->modifyLimitQuery(
$sql, $this->maxResults, $this->firstResult
);
// Add the columns to the ResultSetMapping. It's not really nice but
// it works. Preferably I'd clear the RSM or simply create a new one
// but that is not possible from inside the output walker, so we dirty
// up the one we have.
foreach ($sqlIdentifier as $property => $alias) {
$this->rsm->addScalarResult($alias, $property);
}
return $sql;
}
}

View File

@ -21,9 +21,12 @@ namespace Doctrine\ORM\Tools\Pagination;
use Doctrine\ORM\QueryBuilder;
use Doctrine\ORM\Query;
use Doctrine\ORM\Query\ResultSetMapping;
use Doctrine\ORM\NoResultException;
use Doctrine\ORM\Tools\Pagination\WhereInWalker;
use Doctrine\ORM\Tools\Pagination\WhereInSqlWalker;
use Doctrine\ORM\Tools\Pagination\CountWalker;
use Doctrine\ORM\Tools\Pagination\CountSqlWalker;
use Countable;
use IteratorAggregate;
use ArrayIterator;
@ -49,6 +52,11 @@ class Paginator implements \Countable, \IteratorAggregate
*/
private $fetchJoinCollection;
/**
* @var bool|null
*/
private $useSqlWalkers;
/**
* @var int
*/
@ -90,6 +98,28 @@ class Paginator implements \Countable, \IteratorAggregate
return $this->fetchJoinCollection;
}
/**
* Returns whether the paginator will use an SQL TreeWalker
*
* @return bool|null
*/
public function getUseSqlWalkers()
{
return $this->useSqlWalkers;
}
/**
* Set whether the paginator will use an SQL TreeWalker
*
* @param bool|null $useSqlWalkers
* @return $this
*/
public function setUseSqlWalkers($useSqlWalkers)
{
$this->useSqlWalkers = $useSqlWalkers;
return $this;
}
/**
* {@inheritdoc}
*/
@ -103,7 +133,16 @@ class Paginator implements \Countable, \IteratorAggregate
$countQuery->setHint(CountWalker::HINT_DISTINCT, true);
}
$countQuery->setHint(Query::HINT_CUSTOM_TREE_WALKERS, array('Doctrine\ORM\Tools\Pagination\CountWalker'));
if ($this->useSqlWalker($countQuery)) {
$rsm = new ResultSetMapping();
$rsm->addScalarResult('_dctrn_count', 'count');
$countQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\CountSqlWalker');
$countQuery->setResultSetMapping($rsm);
} else {
$countQuery->setHint(Query::HINT_CUSTOM_TREE_WALKERS, array('Doctrine\ORM\Tools\Pagination\CountWalker'));
}
$countQuery->setFirstResult(null)->setMaxResults(null);
try {
@ -127,9 +166,14 @@ class Paginator implements \Countable, \IteratorAggregate
if ($this->fetchJoinCollection) {
$subQuery = $this->cloneQuery($this->query);
$subQuery->setHint(Query::HINT_CUSTOM_TREE_WALKERS, array('Doctrine\ORM\Tools\Pagination\LimitSubqueryWalker'))
->setFirstResult($offset)
->setMaxResults($length);
if ($this->useSqlWalker($subQuery)) {
$subQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubquerySqlWalker');
} else {
$subQuery->setHint(Query::HINT_CUSTOM_TREE_WALKERS, array('Doctrine\ORM\Tools\Pagination\LimitSubqueryWalker'));
}
$subQuery->setFirstResult($offset)->setMaxResults($length);
$ids = array_map('current', $subQuery->getScalarResult());
@ -176,5 +220,21 @@ class Paginator implements \Countable, \IteratorAggregate
return $cloneQuery;
}
/**
* Determine whether to use an SQL TreeWalker for the query
*
* @param Query $query The query.
*
* @return bool
*/
private function useSqlWalker(Query $query)
{
if ($this->useSqlWalkers === null) {
return (Boolean) $query->getHint(Query::HINT_CUSTOM_OUTPUT_WALKER) == false;
}
return $this->useSqlWalkers;
}
}

View File

@ -30,6 +30,7 @@ class PaginationTest extends \Doctrine\Tests\OrmFunctionalTestCase
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query);
$paginator->setUseSqlWalkers(false);
$this->assertEquals(3, count($paginator));
}
@ -39,15 +40,27 @@ class PaginationTest extends \Doctrine\Tests\OrmFunctionalTestCase
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query);
$paginator->setUseSqlWalkers(false);
$this->assertEquals(3, count($paginator));
}
public function testCountComplexWithSqlWalker()
{
$dql = "SELECT g, COUNT(u.id) AS userCount FROM Doctrine\Tests\Models\CMS\CmsGroup g LEFT JOIN g.users u GROUP BY g.id HAVING userCount > 0";
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query);
$paginator->setUseSqlWalkers(true);
$this->assertEquals(9, count($paginator));
}
public function testIterateSimpleWithoutJoinFetchJoinHandlingOff()
{
$dql = "SELECT u FROM Doctrine\Tests\Models\CMS\CmsUser u";
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query, false);
$paginator->setUseSqlWalkers(false);
$data = array();
foreach ($paginator as $user) {
@ -62,6 +75,7 @@ class PaginationTest extends \Doctrine\Tests\OrmFunctionalTestCase
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query, true);
$paginator->setUseSqlWalkers(false);
$data = array();
foreach ($paginator as $user) {
@ -76,6 +90,7 @@ class PaginationTest extends \Doctrine\Tests\OrmFunctionalTestCase
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query, true);
$paginator->setUseSqlWalkers(false);
$data = array();
foreach ($paginator as $user) {
@ -84,6 +99,40 @@ class PaginationTest extends \Doctrine\Tests\OrmFunctionalTestCase
$this->assertEquals(3, count($data));
}
public function testIterateComplexWithSqlWalker()
{
$dql = "SELECT g, COUNT(u.id) AS userCount FROM Doctrine\Tests\Models\CMS\CmsGroup g LEFT JOIN g.users u GROUP BY g.id HAVING userCount > 0";
$query = $this->_em->createQuery($dql);
$paginator = new Paginator($query);
$paginator->setUseSqlWalkers(true);
$data = array();
foreach ($paginator as $user) {
$data[] = $user;
}
$this->assertEquals(9, count($data));
}
public function testDetectSqlWalker()
{
// This query works using the SQL walkers but causes an exception using the TreeWalker
$dql = "SELECT g, COUNT(u.id) AS userCount FROM Doctrine\Tests\Models\CMS\CmsGroup g LEFT JOIN g.users u GROUP BY g.id HAVING userCount > 0";
$query = $this->_em->createQuery($dql);
// If the Paginator detects the custom SQL walker it should fall back to using the
// Tree walkers for pagination, which leads to an exception. If the query works, the SQL walkers were used
$query->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Query\SqlWalker');
$paginator = new Paginator($query);
try {
count($paginator);
$this->fail('Paginator did not detect custom SQL walker');
} catch (\PHPUnit_Framework_Error_Notice $e) {
$this->assertEquals('Undefined index: userCount', $e->getMessage());
}
}
public function populate()
{
for ($i = 0; $i < 3; $i++) {

View File

@ -0,0 +1,48 @@
<?php
namespace Doctrine\Tests\ORM\Tools\Pagination;
use Doctrine\ORM\Query;
use Doctrine\ORM\Tools\Pagination\CountWalker;
class CountSqlWalkerTest extends PaginationTestCase
{
public function testCountQuery()
{
$query = $this->entityManager->createQuery(
'SELECT p, c, a FROM Doctrine\Tests\ORM\Tools\Pagination\BlogPost p JOIN p.category c JOIN p.author a');
$query->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\CountSqlWalker');
$query->setHint(CountWalker::HINT_DISTINCT, true);
$query->setFirstResult(null)->setMaxResults(null);
$this->assertEquals(
"SELECT COUNT(*) AS _dctrn_count FROM (SELECT DISTINCT id0 FROM (SELECT b0_.id AS id0, c1_.id AS id1, a2_.id AS id2, a2_.name AS name3, b0_.author_id AS author_id4, b0_.category_id AS category_id5 FROM BlogPost b0_ INNER JOIN Category c1_ ON b0_.category_id = c1_.id INNER JOIN Author a2_ ON b0_.author_id = a2_.id) AS _dctrn_result) AS _dctrn_table", $query->getSql()
);
}
public function testCountQuery_MixedResultsWithName()
{
$query = $this->entityManager->createQuery(
'SELECT a, sum(a.name) as foo FROM Doctrine\Tests\ORM\Tools\Pagination\Author a');
$query->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\CountSqlWalker');
$query->setHint(CountWalker::HINT_DISTINCT, true);
$query->setFirstResult(null)->setMaxResults(null);
$this->assertEquals(
"SELECT COUNT(*) AS _dctrn_count FROM (SELECT DISTINCT id0 FROM (SELECT a0_.id AS id0, a0_.name AS name1, sum(a0_.name) AS sclr2 FROM Author a0_) AS _dctrn_result) AS _dctrn_table", $query->getSql()
);
}
public function testCountQuery_Having()
{
$query = $this->entityManager->createQuery(
'SELECT g, u, count(u.id) AS userCount FROM Doctrine\Tests\ORM\Tools\Pagination\Group g LEFT JOIN g.users u GROUP BY g.id HAVING userCount > 0');
$query->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\CountSqlWalker');
$query->setFirstResult(null)->setMaxResults(null);
$this->assertEquals(
"SELECT COUNT(*) AS _dctrn_count FROM (SELECT DISTINCT id1 FROM (SELECT count(u0_.id) AS sclr0, g1_.id AS id1, u0_.id AS id2 FROM groups g1_ LEFT JOIN user_group u2_ ON g1_.id = u2_.group_id LEFT JOIN User u0_ ON u0_.id = u2_.user_id GROUP BY g1_.id HAVING sclr0 > 0) AS _dctrn_result) AS _dctrn_table", $query->getSql()
);
}
}

View File

@ -0,0 +1,33 @@
<?php
namespace Doctrine\Tests\ORM\Tools\Pagination;
use Doctrine\ORM\Query;
class LimitSubquerySqlWalkerTest extends PaginationTestCase
{
public function testLimitSubquery()
{
$query = $this->entityManager->createQuery(
'SELECT p, c, a FROM Doctrine\Tests\ORM\Tools\Pagination\MyBlogPost p JOIN p.category c JOIN p.author a');
$limitQuery = clone $query;
$limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubquerySqlWalker');
$this->assertEquals(
"SELECT DISTINCT id0 FROM (SELECT m0_.id AS id0, c1_.id AS id1, a2_.id AS id2, a2_.name AS name3, m0_.author_id AS author_id4, m0_.category_id AS category_id5 FROM MyBlogPost m0_ INNER JOIN Category c1_ ON m0_.category_id = c1_.id INNER JOIN Author a2_ ON m0_.author_id = a2_.id) AS _dctrn_result", $limitQuery->getSql()
);
}
public function testCountQuery_MixedResultsWithName()
{
$query = $this->entityManager->createQuery(
'SELECT a, sum(a.name) as foo FROM Doctrine\Tests\ORM\Tools\Pagination\Author a');
$limitQuery = clone $query;
$limitQuery->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, 'Doctrine\ORM\Tools\Pagination\LimitSubquerySqlWalker');
$this->assertEquals(
"SELECT DISTINCT id0 FROM (SELECT a0_.id AS id0, a0_.name AS name1, sum(a0_.name) AS sclr2 FROM Author a0_) AS _dctrn_result", $limitQuery->getSql()
);
}
}