Skip to content

Commit 4169b5a

Browse files
committed
Add CTE support to select in QueryBuilder
1 parent 052545f commit 4169b5a

File tree

7 files changed

+230
-1
lines changed

7 files changed

+230
-1
lines changed

docs/en/reference/query-builder.rst

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -368,6 +368,29 @@ or QueryBuilder instances to one of the following methods:
368368
->orderBy('field', 'DESC')
369369
->setMaxResults(100);
370370
371+
WITH-Clause
372+
~~~~~~~~~~~
373+
374+
The with method is used to define Common Table Expressions (CTEs).
375+
376+
* ``with(string $name, QueryBuilder $queryBuilder)``
377+
378+
.. code-block:: php
379+
380+
<?php
381+
382+
$cteQueryBuilder
383+
->select('id', 'name')
384+
->from('a_table')
385+
->where('name = :q');
386+
387+
$queryBuilder
388+
->with('filtered_by_name', $cteQueryBuilder)
389+
->select('id', 'name')
390+
->from('filtered_by_name');
391+
392+
Multiple CTEs can be defined by calling the with method multiple times.
393+
371394
Building Expressions
372395
--------------------
373396

src/Query/QueryBuilder.php

Lines changed: 63 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -15,6 +15,7 @@
1515
use Doctrine\DBAL\Query\Expression\ExpressionBuilder;
1616
use Doctrine\DBAL\Query\ForUpdate\ConflictResolutionMode;
1717
use Doctrine\DBAL\Result;
18+
use Doctrine\DBAL\SQL\Builder\WithSQLBuilder;
1819
use Doctrine\DBAL\Statement;
1920
use Doctrine\DBAL\Types\Type;
2021

@@ -160,6 +161,13 @@ class QueryBuilder
160161
*/
161162
private array $unionParts = [];
162163

164+
/**
165+
* The common table expression parts.
166+
*
167+
* @var With[]
168+
*/
169+
private array $withParts = [];
170+
163171
/**
164172
* The query cache profile used for caching results.
165173
*/
@@ -557,6 +565,53 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType:
557565
return $this;
558566
}
559567

568+
/**
569+
* Specifies a CTE to be used to build a With query.
570+
* Replaces any previously specified parts.
571+
*
572+
* <code>
573+
* $qb = $conn->createQueryBuilder()
574+
* ->with('cte_a', 'SELECT 1 AS field1');
575+
* </code>
576+
*
577+
* @return $this
578+
*/
579+
public function with(string $name, string|QueryBuilder $part): self
580+
{
581+
$this->withParts = [new With($name, $part)];
582+
583+
$this->sql = null;
584+
585+
return $this;
586+
}
587+
588+
/**
589+
* Add a CTE to be used to build a With query.
590+
* Replaces any previously specified parts.
591+
*
592+
* <code>
593+
* $qb = $conn->createQueryBuilder()
594+
* ->with('cte_a', 'SELECT 1 AS field_a')
595+
* ->addWith('cte_b', 'SELECT 1 AS field_b');
596+
* </code>
597+
*
598+
* @return $this
599+
*
600+
* @throws QueryException
601+
*/
602+
public function addWith(string $name, string|QueryBuilder $part): self
603+
{
604+
if (count($this->withParts) === 0) {
605+
throw new QueryException('No initial WITH part set, use with() to set one first.');
606+
}
607+
608+
$this->withParts[] = new With($name, $part);
609+
610+
$this->sql = null;
611+
612+
return $this;
613+
}
614+
560615
/**
561616
* Specifies an item that is to be returned in the query result.
562617
* Replaces any previously specified selections, if any.
@@ -1266,7 +1321,12 @@ private function getSQLForSelect(): string
12661321
throw new QueryException('No SELECT expressions given. Please use select() or addSelect().');
12671322
}
12681323

1269-
return $this->connection->getDatabasePlatform()
1324+
$withSQL = '';
1325+
if (count($this->withParts) > 0) {
1326+
$withSQL = (new WithSQLBuilder())->buildSQL(new WithQuery($this->withParts));
1327+
}
1328+
1329+
$selectSQL = $this->connection->getDatabasePlatform()
12701330
->createSelectSQLBuilder()
12711331
->buildSQL(
12721332
new SelectQuery(
@@ -1281,6 +1341,8 @@ private function getSQLForSelect(): string
12811341
$this->forUpdate,
12821342
),
12831343
);
1344+
1345+
return $withSQL . $selectSQL;
12841346
}
12851347

12861348
/**

src/Query/With.php

Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,15 @@
1+
<?php
2+
3+
declare(strict_types=1);
4+
5+
namespace Doctrine\DBAL\Query;
6+
7+
/** @internal */
8+
final class With
9+
{
10+
public function __construct(
11+
public readonly string $name,
12+
public readonly string|QueryBuilder $query,
13+
) {
14+
}
15+
}

src/Query/WithQuery.php

Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
<?php
2+
3+
declare(strict_types=1);
4+
5+
namespace Doctrine\DBAL\Query;
6+
7+
final class WithQuery
8+
{
9+
/**
10+
* @internal This class should be instantiated only by {@link QueryBuilder}.
11+
*
12+
* @param With[] $withParts
13+
*/
14+
public function __construct(
15+
private readonly array $withParts,
16+
) {
17+
}
18+
19+
/** @return With[] */
20+
public function withParts(): array
21+
{
22+
return $this->withParts;
23+
}
24+
}

src/SQL/Builder/WithSQLBuilder.php

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,23 @@
1+
<?php
2+
3+
declare(strict_types=1);
4+
5+
namespace Doctrine\DBAL\SQL\Builder;
6+
7+
use Doctrine\DBAL\Query\WithQuery;
8+
9+
use function implode;
10+
use function sprintf;
11+
12+
final class WithSQLBuilder
13+
{
14+
public function buildSQL(WithQuery $query): string
15+
{
16+
$parts = [];
17+
foreach ($query->withParts() as $part) {
18+
$parts[] = sprintf('%s AS (%s)', $part->name, (string) $part->query);
19+
}
20+
21+
return 'WITH ' . implode(', ', $parts) . ' ';
22+
}
23+
}

tests/Functional/Query/QueryBuilderTest.php

Lines changed: 56 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44

55
namespace Doctrine\DBAL\Tests\Functional\Query;
66

7+
use Doctrine\DBAL\ArrayParameterType;
78
use Doctrine\DBAL\DriverManager;
89
use Doctrine\DBAL\Exception;
910
use Doctrine\DBAL\ParameterType;
@@ -14,6 +15,7 @@
1415
use Doctrine\DBAL\Platforms\MySQLPlatform;
1516
use Doctrine\DBAL\Platforms\SQLitePlatform;
1617
use Doctrine\DBAL\Query\ForUpdate\ConflictResolutionMode;
18+
use Doctrine\DBAL\Query\QueryException;
1719
use Doctrine\DBAL\Query\UnionType;
1820
use Doctrine\DBAL\Schema\Table;
1921
use Doctrine\DBAL\Tests\FunctionalTestCase;
@@ -332,6 +334,49 @@ public function testUnionAndAddUnionWorksWithQueryBuilderPartsAndReturnsExpected
332334
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
333335
}
334336

337+
public function testWithNamedParameterCTE(): void
338+
{
339+
if (! $this->platformSupportsCTEs()) {
340+
self::markTestSkipped('The database platform does not support CTE.');
341+
}
342+
343+
$expectedRows = $this->prepareExpectedRows([['id' => 1]]);
344+
$qb = $this->connection->createQueryBuilder();
345+
346+
$cteQueryBuilder1 = $this->connection->createQueryBuilder();
347+
$cteQueryBuilder1->select('id')
348+
->from('for_update')
349+
->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER)));
350+
351+
$qb->with('filtered_for_update', $cteQueryBuilder1)
352+
->select('id')
353+
->from('filtered_for_update');
354+
355+
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
356+
}
357+
358+
public function testWithPositionalParameterCTE(): void
359+
{
360+
if (! $this->platformSupportsCTEs()) {
361+
self::markTestSkipped('The database platform does not support CTE.');
362+
}
363+
364+
$expectedRows = $this->prepareExpectedRows([['id' => 1]]);
365+
$qb = $this->connection->createQueryBuilder();
366+
367+
$cteQueryBuilder1 = $this->connection->createQueryBuilder();
368+
$cteQueryBuilder1->select('id')
369+
->from('for_update')
370+
->where($qb->expr()->in('id', $qb->createPositionalParameter([1, 2], ArrayParameterType::INTEGER)));
371+
372+
$qb->with('filtered_for_update', $cteQueryBuilder1)
373+
->select('id')
374+
->from('filtered_for_update')
375+
->where($qb->expr()->eq('id', $qb->createPositionalParameter(1, ParameterType::INTEGER)));
376+
377+
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
378+
}
379+
335380
/**
336381
* @param array<array<string, int>> $rows
337382
*
@@ -380,4 +425,15 @@ private function platformSupportsSkipLocked(): bool
380425

381426
return ! $platform instanceof SQLitePlatform;
382427
}
428+
429+
private function platformSupportsCTEs(): bool
430+
{
431+
$platform = $this->connection->getDatabasePlatform();
432+
433+
if (! $platform instanceof MySQLPlatform) {
434+
return true;
435+
}
436+
437+
return $this->connection->getServerVersion() >= '8.0.11';
438+
}
383439
}

tests/Query/QueryBuilderTest.php

Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -850,6 +850,32 @@ public function testSelectAllWithoutTableAlias(): void
850850
self::assertEquals('SELECT * FROM users', (string) $qb);
851851
}
852852

853+
public function testSelectWithCTE(): void
854+
{
855+
$qbWith = new QueryBuilder($this->conn);
856+
$qbWith->select('ta.id', 'ta.name', 'ta.table_b_id')
857+
->from('table_a', 'ta')
858+
->where('ta.name LIKE :name');
859+
860+
$qbAddWith = new QueryBuilder($this->conn);
861+
$qbAddWith->select('ca.id')
862+
->from('cte_a', 'ca')
863+
->join('ca', 'table_b', 'tb', 'ca.table_b_id = tb.id');
864+
865+
$qb = new QueryBuilder($this->conn);
866+
$qb->with('cte_a', $qbWith)
867+
->addWith('cte_b', $qbAddWith)
868+
->select('cb.*')
869+
->from('cte_b', 'cb');
870+
871+
self::assertEquals(
872+
'WITH cte_a AS (SELECT ta.id, ta.name, ta.table_b_id FROM table_a ta WHERE ta.name LIKE :name)'
873+
. ', cte_b AS (SELECT ca.id FROM cte_a ca INNER JOIN table_b tb ON ca.table_b_id = tb.id) '
874+
. 'SELECT cb.* FROM cte_b cb',
875+
(string) $qb,
876+
);
877+
}
878+
853879
public function testGetParameterType(): void
854880
{
855881
$qb = new QueryBuilder($this->conn);

0 commit comments

Comments
 (0)