Skip to content

Commit 6559c32

Browse files
committed
Add CTE support to select in QueryBuilder
1 parent 052545f commit 6559c32

File tree

9 files changed

+288
-1
lines changed

9 files changed

+288
-1
lines changed

docs/en/reference/query-builder.rst

Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -368,6 +368,26 @@ or QueryBuilder instances to one of the following methods:
368368
->orderBy('field', 'DESC')
369369
->setMaxResults(100);
370370
371+
WITH-Clause
372+
~~~~~~~~~~~
373+
374+
To define Common Table Expressions (CTEs) that can be used in select query.
375+
376+
* ``with(string $name, string|QueryBuilder $queryBuilder, array $columns = [])``
377+
378+
.. code-block:: php
379+
380+
<?php
381+
382+
$queryBuilder
383+
->with('cte_a', 'SELECT id FROM table_a')
384+
->with('cte_b', 'SELECT id FROM table_b')
385+
->select('id')
386+
->from('cte_b', 'b')
387+
->join('b', 'cte_a', 'a', 'a.id = b.id');
388+
389+
Multiple CTEs can be defined by calling the with method multiple times.
390+
371391
Building Expressions
372392
--------------------
373393

src/Platforms/AbstractPlatform.php

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,7 @@
3131
use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder;
3232
use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder;
3333
use Doctrine\DBAL\SQL\Builder\UnionSQLBuilder;
34+
use Doctrine\DBAL\SQL\Builder\WithSQLBuilder;
3435
use Doctrine\DBAL\SQL\Parser;
3536
use Doctrine\DBAL\TransactionIsolationLevel;
3637
use Doctrine\DBAL\Types;
@@ -802,6 +803,11 @@ public function createUnionSQLBuilder(): UnionSQLBuilder
802803
return new DefaultUnionSQLBuilder($this);
803804
}
804805

806+
public function createWithSQLBuilder(): WithSQLBuilder
807+
{
808+
return new WithSQLBuilder();
809+
}
810+
805811
/**
806812
* @internal
807813
*

src/Platforms/MySQL80Platform.php

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -7,6 +7,7 @@
77
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
88
use Doctrine\DBAL\Platforms\Keywords\MySQL80Keywords;
99
use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder;
10+
use Doctrine\DBAL\SQL\Builder\WithSQLBuilder;
1011
use Doctrine\Deprecations\Deprecation;
1112

1213
/**
@@ -32,4 +33,9 @@ public function createSelectSQLBuilder(): SelectSQLBuilder
3233
{
3334
return AbstractPlatform::createSelectSQLBuilder();
3435
}
36+
37+
public function createWithSQLBuilder(): WithSQLBuilder
38+
{
39+
return AbstractPlatform::createWithSQLBuilder();
40+
}
3541
}

src/Platforms/MySQLPlatform.php

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

55
namespace Doctrine\DBAL\Platforms;
66

7+
use Doctrine\DBAL\Platforms\Exception\NotSupported;
78
use Doctrine\DBAL\Platforms\Keywords\KeywordList;
89
use Doctrine\DBAL\Platforms\Keywords\MySQLKeywords;
910
use Doctrine\DBAL\Schema\Index;
11+
use Doctrine\DBAL\SQL\Builder\WithSQLBuilder;
1012
use Doctrine\DBAL\Types\BlobType;
1113
use Doctrine\DBAL\Types\TextType;
1214
use Doctrine\Deprecations\Deprecation;
@@ -35,6 +37,11 @@ public function getDefaultValueDeclarationSQL(array $column): string
3537
return parent::getDefaultValueDeclarationSQL($column);
3638
}
3739

40+
public function createWithSQLBuilder(): WithSQLBuilder
41+
{
42+
throw NotSupported::new(__METHOD__);
43+
}
44+
3845
/**
3946
* {@inheritDoc}
4047
*/

src/Query/QueryBuilder.php

Lines changed: 45 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -160,6 +160,13 @@ class QueryBuilder
160160
*/
161161
private array $unionParts = [];
162162

163+
/**
164+
* The common table expression parts.
165+
*
166+
* @var With[]
167+
*/
168+
private array $withParts = [];
169+
163170
/**
164171
* The query cache profile used for caching results.
165172
*/
@@ -557,6 +564,33 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType:
557564
return $this;
558565
}
559566

567+
/**
568+
* Add a Common Table Expression to be used for a select query.
569+
*
570+
* <code>
571+
* // WITH cte_name AS (SELECT 1 AS column1)
572+
* $qb = $conn->createQueryBuilder()
573+
* ->with('cte_name', 'SELECT 1 AS column1');
574+
*
575+
* // WITH cte_name(column1) AS (SELECT 1 AS column1)
576+
* $qb = $conn->createQueryBuilder()
577+
* ->with('cte_name', 'SELECT 1 AS column1', ['column1']);
578+
* </code>
579+
*
580+
* @param string $name The name of the CTE
581+
* @param string[] $columns The optional columns list to select in the CTE.
582+
*
583+
* @return $this This QueryBuilder instance.
584+
*/
585+
public function with(string $name, string|QueryBuilder $part, array $columns = []): self
586+
{
587+
$this->withParts[] = new With($name, $part, $columns);
588+
589+
$this->sql = null;
590+
591+
return $this;
592+
}
593+
560594
/**
561595
* Specifies an item that is to be returned in the query result.
562596
* Replaces any previously specified selections, if any.
@@ -1266,7 +1300,15 @@ private function getSQLForSelect(): string
12661300
throw new QueryException('No SELECT expressions given. Please use select() or addSelect().');
12671301
}
12681302

1269-
return $this->connection->getDatabasePlatform()
1303+
$databasePlatform = $this->connection->getDatabasePlatform();
1304+
$selectParts = [];
1305+
if (count($this->withParts) > 0) {
1306+
$selectParts[] = $databasePlatform
1307+
->createWithSQLBuilder()
1308+
->buildSQL(...$this->withParts);
1309+
}
1310+
1311+
$selectParts[] = $databasePlatform
12701312
->createSelectSQLBuilder()
12711313
->buildSQL(
12721314
new SelectQuery(
@@ -1281,6 +1323,8 @@ private function getSQLForSelect(): string
12811323
$this->forUpdate,
12821324
),
12831325
);
1326+
1327+
return implode(' ', $selectParts);
12841328
}
12851329

12861330
/**

src/Query/With.php

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

src/SQL/Builder/WithSQLBuilder.php

Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,31 @@
1+
<?php
2+
3+
declare(strict_types=1);
4+
5+
namespace Doctrine\DBAL\SQL\Builder;
6+
7+
use Doctrine\DBAL\Query\With;
8+
9+
use function array_merge;
10+
use function count;
11+
use function implode;
12+
13+
final class WithSQLBuilder
14+
{
15+
public function buildSQL(With $firstExpression, With ...$otherExpressions): string
16+
{
17+
$withParts = [];
18+
19+
foreach (array_merge([$firstExpression], $otherExpressions) as $part) {
20+
$withPart = [$part->name];
21+
if (count($part->columns) > 0) {
22+
$withPart[] = '(' . implode(', ', $part->columns) . ')';
23+
}
24+
25+
$withPart[] = ' AS (' . $part->query . ')';
26+
$withParts[] = implode('', $withPart);
27+
}
28+
29+
return 'WITH ' . implode(', ', $withParts);
30+
}
31+
}

tests/Functional/Query/QueryBuilderTest.php

Lines changed: 125 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,10 +4,12 @@
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;
1011
use Doctrine\DBAL\Platforms\DB2Platform;
12+
use Doctrine\DBAL\Platforms\Exception\NotSupported;
1113
use Doctrine\DBAL\Platforms\MariaDB1060Platform;
1214
use Doctrine\DBAL\Platforms\MariaDBPlatform;
1315
use Doctrine\DBAL\Platforms\MySQL80Platform;
@@ -332,6 +334,117 @@ public function testUnionAndAddUnionWorksWithQueryBuilderPartsAndReturnsExpected
332334
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
333335
}
334336

337+
public function testSelectWithCTENamedParameter(): void
338+
{
339+
if (! $this->platformSupportsCTEs()) {
340+
self::markTestSkipped('The database platform does not support CTE.');
341+
}
342+
343+
if (! $this->platformSupportsCTEColumnDefinition()) {
344+
self::markTestSkipped('The database platform does not support CTE column definition.');
345+
}
346+
347+
$expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]);
348+
$qb = $this->connection->createQueryBuilder();
349+
350+
$cteQueryBuilder = $this->connection->createQueryBuilder();
351+
$cteQueryBuilder->select('id AS virtual_id')
352+
->from('for_update')
353+
->where('virtual_id = :id');
354+
355+
$qb->with('cte_a', $cteQueryBuilder, ['virtual_id'])
356+
->select('virtual_id')
357+
->from('cte_a')
358+
->setParameter('id', 1);
359+
360+
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
361+
}
362+
363+
public function testSelectWithCTEPositionalParameter(): void
364+
{
365+
if (! $this->platformSupportsCTEs()) {
366+
self::markTestSkipped('The database platform does not support CTE.');
367+
}
368+
369+
if (! $this->platformSupportsCTEColumnDefinition()) {
370+
self::markTestSkipped('The database platform does not support CTE column definition.');
371+
}
372+
373+
$expectedRows = $this->prepareExpectedRows([['virtual_id' => 1]]);
374+
$qb = $this->connection->createQueryBuilder();
375+
376+
$cteQueryBuilder1 = $this->connection->createQueryBuilder();
377+
$cteQueryBuilder1->select('id AS virtual_id')
378+
->from('for_update')
379+
->where($qb->expr()->eq('virtual_id', '?'));
380+
381+
$cteQueryBuilder2 = $this->connection->createQueryBuilder();
382+
$cteQueryBuilder2->select('id AS virtual_id')
383+
->from('for_update')
384+
->where($qb->expr()->in('id', '?'));
385+
386+
$qb->with('cte_a', $cteQueryBuilder1, ['virtual_id'])
387+
->with('cte_b', $cteQueryBuilder2, ['virtual_id'])
388+
->select('a.virtual_id')
389+
->from('cte_a', 'a')
390+
->join('a', 'cte_b', 'b', 'a.virtual_id = b.virtual_id')
391+
->setParameters([1, [1, 2]], [ParameterType::INTEGER, ArrayParameterType::INTEGER]);
392+
393+
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
394+
}
395+
396+
public function testSelectWithCTEUnion(): void
397+
{
398+
if (! $this->platformSupportsCTEs()) {
399+
self::markTestSkipped('The database platform does not support CTE.');
400+
}
401+
402+
$expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]);
403+
$qb = $this->connection->createQueryBuilder();
404+
405+
$subQueryBuilder1 = $this->connection->createQueryBuilder();
406+
$subQueryBuilder1->select('id')
407+
->from('for_update')
408+
->where($qb->expr()->eq('id', '?'));
409+
410+
$subQueryBuilder2 = $this->connection->createQueryBuilder();
411+
$subQueryBuilder2->select('id')
412+
->from('for_update')
413+
->where($qb->expr()->eq('id', '?'));
414+
415+
$subQueryBuilder3 = $this->connection->createQueryBuilder();
416+
$subQueryBuilder3->union($subQueryBuilder1)
417+
->addUnion($subQueryBuilder2, UnionType::DISTINCT);
418+
419+
$qb->with('cte_a', $subQueryBuilder3)
420+
->select('id')
421+
->from('cte_a')
422+
->orderBy('id', 'DESC')
423+
->setParameters([1, 2]);
424+
425+
self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative());
426+
}
427+
428+
public function testPlatformDoesNotSupportCTE(): void
429+
{
430+
if ($this->platformSupportsCTEs()) {
431+
self::markTestSkipped('The database platform does support CTE.');
432+
}
433+
434+
$qb = $this->connection->createQueryBuilder();
435+
436+
$cteQueryBuilder = $this->connection->createQueryBuilder();
437+
$cteQueryBuilder->select('id')
438+
->from('for_update');
439+
440+
$qb->with('cte_a', $cteQueryBuilder)
441+
->select('id')
442+
->from('cte_a');
443+
444+
self::expectException(NotSupported::class);
445+
$qb->executeQuery();
446+
}
447+
335448
/**
336449
* @param array<array<string, int>> $rows
337450
*
@@ -380,4 +493,16 @@ private function platformSupportsSkipLocked(): bool
380493

381494
return ! $platform instanceof SQLitePlatform;
382495
}
496+
497+
private function platformSupportsCTEs(): bool
498+
{
499+
$platform = $this->connection->getDatabasePlatform();
500+
501+
return ! $platform instanceof MySQLPlatform || $platform instanceof MySQL80Platform;
502+
}
503+
504+
private function platformSupportsCTEColumnDefinition(): bool
505+
{
506+
return $this->connection->getDatabasePlatform() instanceof SQLitePlatform;
507+
}
383508
}

0 commit comments

Comments
 (0)