Skip to content

Commit

Permalink
Add CTE support to select in QueryBuilder
Browse files Browse the repository at this point in the history
  • Loading branch information
nio-dtp committed Nov 29, 2024
1 parent 052545f commit ac83c92
Show file tree
Hide file tree
Showing 9 changed files with 317 additions and 1 deletion.
21 changes: 21 additions & 0 deletions docs/en/reference/query-builder.rst
Original file line number Diff line number Diff line change
Expand Up @@ -368,6 +368,27 @@ or QueryBuilder instances to one of the following methods:
->orderBy('field', 'DESC')
->setMaxResults(100);
WITH-Clause
~~~~~~~~~~~

To define Common Table Expressions (CTEs) that can be used in select query.

* ``with(string $name, string|QueryBuilder $queryBuilder, array $fields = [])``
* ``addWith(string $name, string|QueryBuilder $queryBuilder, array $fields = [])``

.. code-block:: php
<?php
$queryBuilder
->with('cte_a', 'SELECT id FROM table_a')
->addWith('cte_b', 'SELECT id FROM table_b')
->select('id')
->from('cte_b', 'b')
->join('b', 'cte_a', 'a', 'a.id = b.id');
Multiple CTEs can be defined by calling the addWith method multiple times.

Building Expressions
--------------------

Expand Down
7 changes: 7 additions & 0 deletions src/Platforms/AbstractPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -29,8 +29,10 @@
use Doctrine\DBAL\Schema\UniqueConstraint;
use Doctrine\DBAL\SQL\Builder\DefaultSelectSQLBuilder;
use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder;
use Doctrine\DBAL\SQL\Builder\DefaultWithSQLBuilder;
use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder;
use Doctrine\DBAL\SQL\Builder\UnionSQLBuilder;
use Doctrine\DBAL\SQL\Builder\WithSQLBuilder;
use Doctrine\DBAL\SQL\Parser;
use Doctrine\DBAL\TransactionIsolationLevel;
use Doctrine\DBAL\Types;
Expand Down Expand Up @@ -802,6 +804,11 @@ public function createUnionSQLBuilder(): UnionSQLBuilder
return new DefaultUnionSQLBuilder($this);
}

public function createWithSQLBuilder(): WithSQLBuilder
{
return new DefaultWithSQLBuilder();
}

/**
* @internal
*
Expand Down
68 changes: 67 additions & 1 deletion src/Query/QueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -160,6 +160,13 @@ class QueryBuilder
*/
private array $unionParts = [];

/**
* The common table expression parts.
*
* @var With[]
*/
private array $withParts = [];

/**
* The query cache profile used for caching results.
*/
Expand Down Expand Up @@ -557,6 +564,56 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType:
return $this;
}

/**
* Add a Common Table Expression to be used for a select query.
* Replaces any previously specified parts.
*
* <code>
* $qb = $conn->createQueryBuilder()
* ->with('cte_a', 'SELECT 1 AS field1');
* </code>
*
* @param string[] $fields The optional fields to select in the CTE.
*
* @return $this
*/
public function with(string $name, string|QueryBuilder $part, array $fields = []): self
{
$this->withParts = [new With($name, $part, $fields)];

$this->sql = null;

return $this;
}

/**
* Add a Common Table Expression to be used for a select query.
*
* <code>
* $qb = $conn->createQueryBuilder()
* ->with('cte_a', 'SELECT 1 AS field_a')
* ->addWith('cte_b', 'SELECT 1 AS field_b');
* </code>
*
* @param string[] $fields The optional fields to select in the CTE.
*
* @return $this
*
* @throws QueryException
*/
public function addWith(string $name, string|QueryBuilder $part, array $fields = []): self
{
if (count($this->withParts) === 0) {
throw new QueryException('No initial WITH part set, use with() to set one first.');
}

$this->withParts[] = new With($name, $part, $fields);

$this->sql = null;

return $this;
}

/**
* Specifies an item that is to be returned in the query result.
* Replaces any previously specified selections, if any.
Expand Down Expand Up @@ -1266,7 +1323,14 @@ private function getSQLForSelect(): string
throw new QueryException('No SELECT expressions given. Please use select() or addSelect().');
}

return $this->connection->getDatabasePlatform()
$selectSQL = '';
if (count($this->withParts) > 0) {
$selectSQL .= $this->connection->getDatabasePlatform()
->createWithSQLBuilder()
->buildSQL(new WithQuery($this->withParts));
}

$selectSQL .= $this->connection->getDatabasePlatform()
->createSelectSQLBuilder()
->buildSQL(
new SelectQuery(
Expand All @@ -1281,6 +1345,8 @@ private function getSQLForSelect(): string
$this->forUpdate,
),
);

return $selectSQL;
}

/**
Expand Down
17 changes: 17 additions & 0 deletions src/Query/With.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

/** @internal */
final class With
{
/** @param string[] $fields */
public function __construct(
public readonly string $name,
public readonly string|QueryBuilder $query,
public readonly array $fields = [],
) {
}
}
24 changes: 24 additions & 0 deletions src/Query/WithQuery.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

final class WithQuery
{
/**
* @internal This class should be instantiated only by {@link QueryBuilder}.
*
* @param With[] $withParts
*/
public function __construct(
private readonly array $withParts,
) {
}

/** @return With[] */
public function withParts(): array
{
return $this->withParts;
}
}
37 changes: 37 additions & 0 deletions src/SQL/Builder/DefaultWithSQLBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\SQL\Builder;

use Doctrine\DBAL\Query\With;
use Doctrine\DBAL\Query\WithQuery;

use function array_map;
use function count;
use function implode;
use function sprintf;

final class DefaultWithSQLBuilder implements WithSQLBuilder
{
public function buildSQL(WithQuery $query): string
{
$parts = array_map(
static fn (With $part) => sprintf(
'%s%s AS (%s)',
$part->name,
self::fields($part->fields),
$part->query,
),
$query->withParts(),
);

return 'WITH ' . implode(', ', $parts) . ' ';
}

/** @param string[] $fields */
private static function fields(array $fields): string
{
return count($fields) > 0 ? '(' . implode(', ', $fields) . ')' : '';
}
}
12 changes: 12 additions & 0 deletions src/SQL/Builder/WithSQLBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\SQL\Builder;

use Doctrine\DBAL\Query\WithQuery;

interface WithSQLBuilder
{
public function buildSQL(WithQuery $query): string;
}
88 changes: 88 additions & 0 deletions tests/Functional/Query/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@

namespace Doctrine\DBAL\Tests\Functional\Query;

use Doctrine\DBAL\ArrayParameterType;
use Doctrine\DBAL\DriverManager;
use Doctrine\DBAL\Exception;
use Doctrine\DBAL\ParameterType;
Expand Down Expand Up @@ -332,6 +333,86 @@ public function testUnionAndAddUnionWorksWithQueryBuilderPartsAndReturnsExpected
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
}

public function testSelectWithCTENamedParameter(): void
{
if (! $this->platformSupportsCTEs()) {
self::markTestSkipped('The database platform does not support CTE.');
}

$expectedRows = $this->prepareExpectedRows([['id' => 1]]);
$qb = $this->connection->createQueryBuilder();

$cteQueryBuilder1 = $this->connection->createQueryBuilder();
$cteQueryBuilder1->select('id')
->from('for_update')
->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER)));

$qb->with('cte_a', $cteQueryBuilder1)
->select('id')
->from('cte_a');

self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
}

public function testSelectWithCTEPositionalParameter(): void
{
if (! $this->platformSupportsCTEs()) {
self::markTestSkipped('The database platform does not support CTE.');
}

$expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]);
$qb = $this->connection->createQueryBuilder();

$cteQueryBuilder1 = $this->connection->createQueryBuilder();
$cteQueryBuilder1->select('id AS virtual_id')
->from('for_update')
->where($qb->expr()->eq('id', $qb->createPositionalParameter(1, ParameterType::INTEGER)));

$cteQueryBuilder2 = $this->connection->createQueryBuilder();
$cteQueryBuilder2->select('id AS virtual_id')
->from('for_update')
->where($qb->expr()->in('id', $qb->createPositionalParameter([1, 2], ArrayParameterType::INTEGER)));

$qb->with('cte_a', $cteQueryBuilder1, ['virtual_id'])
->addWith('cte_b', $cteQueryBuilder2, ['virtual_id'])
->select('a.virtual_id')
->from('cte_a', 'a')
->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id');

self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
}

public function testSelectWithCTEUnion(): void
{
if (! $this->platformSupportsCTEs()) {
self::markTestSkipped('The database platform does not support CTE.');
}

$expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]);
$qb = $this->connection->createQueryBuilder();

$subQueryBuilder1 = $this->connection->createQueryBuilder();
$subQueryBuilder1->select('id')
->from('for_update')
->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER)));

$subQueryBuilder2 = $this->connection->createQueryBuilder();
$subQueryBuilder2->select('id')
->from('for_update')
->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER)));

$subQueryBuilder3 = $this->connection->createQueryBuilder();
$subQueryBuilder3->union($subQueryBuilder1)
->addUnion($subQueryBuilder2, UnionType::DISTINCT);

$qb->with('cte_a', $subQueryBuilder3)
->select('id')
->from('cte_a')
->orderBy('id', 'DESC');

self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
}

/**
* @param array<array<string, int>> $rows
*
Expand Down Expand Up @@ -380,4 +461,11 @@ private function platformSupportsSkipLocked(): bool

return ! $platform instanceof SQLitePlatform;
}

private function platformSupportsCTEs(): bool
{
$platform = $this->connection->getDatabasePlatform();

return ! $platform instanceof MySQLPlatform || $platform instanceof MySQL80Platform;
}
}
Loading

0 comments on commit ac83c92

Please sign in to comment.