Skip to content

Commit

Permalink
Rework naming to use CTE everywhere
Browse files Browse the repository at this point in the history
  • Loading branch information
nio-dtp committed Dec 7, 2024
1 parent 11280cd commit c7e00a7
Show file tree
Hide file tree
Showing 6 changed files with 75 additions and 46 deletions.
21 changes: 17 additions & 4 deletions docs/en/reference/query-builder.rst
Original file line number Diff line number Diff line change
Expand Up @@ -368,26 +368,39 @@ or QueryBuilder instances to one of the following methods:
->orderBy('field', 'DESC')
->setMaxResults(100);
WITH-Clause
Common Table Expressions
~~~~~~~~~~~

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

* ``with(string $name, string|QueryBuilder $queryBuilder, array $columns = [])``
* ``with(string $name, string|QueryBuilder $queryBuilder, ?array $columns = null)``

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

Parameters used in a CTE can be defined directly in the QueryBuilder of the CTE.
This way, the CTE builders are naturally composable.

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

Expand Down
6 changes: 3 additions & 3 deletions src/Query/With.php → src/Query/CommonTableExpression.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,13 +5,13 @@
namespace Doctrine\DBAL\Query;

/** @internal */
final class With
final class CommonTableExpression
{
/** @param string[] $columns */
/** @param string[]|null $columns */
public function __construct(
public readonly string $name,
public readonly string|QueryBuilder $query,
public readonly array $columns = [],
public readonly ?array $columns,
) {
}
}
53 changes: 30 additions & 23 deletions src/Query/QueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,7 @@
use function count;
use function implode;
use function is_object;
use function sprintf;
use function substr;

/**
Expand Down Expand Up @@ -163,9 +164,9 @@ class QueryBuilder
/**
* The common table expression parts.
*
* @var With[]
* @var CommonTableExpression[]
*/
private array $withParts = [];
private array $commonTableExpressions = [];

/**
* The query cache profile used for caching results.
Expand Down Expand Up @@ -309,7 +310,7 @@ public function fetchFirstColumn(): array
*/
public function executeQuery(): Result
{
[$params, $types] = $this->boundParameters();
[$params, $types] = $this->buildParametersAndTypes();

return $this->connection->executeQuery(
$this->getSQL(),
Expand All @@ -320,28 +321,28 @@ public function executeQuery(): Result
}

/**
* Retrieve parameters and types bound to all queries (optional CTEs and main query).
* Build then return parameters and types for the query.
*
* @return array{
* list<mixed>|array<string, mixed>,
* WrapperParameterTypeArray,
* } The parameters and types bound to the CTE queries merged with those bound to the main query.
* } The parameters and types for the query.
*/
private function boundParameters(): array
private function buildParametersAndTypes(): array
{
if (count($this->withParts) === 0) {
if (count($this->commonTableExpressions) === 0) {
return [$this->params, $this->types];
}

$cteParams = $cteParamsTypes = [];
$cteParams = $cteParamTypes = [];

foreach ($this->withParts as $withPart) {
if (! $withPart->query instanceof self) {
foreach ($this->commonTableExpressions as $cte) {
if (! $cte->query instanceof self) {
continue;

Check warning on line 341 in src/Query/QueryBuilder.php

View check run for this annotation

Codecov / codecov/patch

src/Query/QueryBuilder.php#L341

Added line #L341 was not covered by tests
}

$cteParams = array_merge($cteParams, $withPart->query->params);
$cteParamsTypes = array_merge($cteParamsTypes, $withPart->query->types);
$cteParams = array_merge($cteParams, $cte->query->params);
$cteParamTypes = array_merge($cteParamTypes, $cte->query->types);
}

if (count($cteParams) === 0) {
Expand All @@ -350,7 +351,7 @@ private function boundParameters(): array

return [
array_merge($cteParams, $this->params),
array_merge($cteParamsTypes, $this->types),
array_merge($cteParamTypes, $this->types),
];
}

Expand Down Expand Up @@ -605,23 +606,29 @@ public function addUnion(string|QueryBuilder $part, UnionType $type = UnionType:
* Add a Common Table Expression to be used for a select query.
*
* <code>
* // WITH cte_name AS (SELECT 1 AS column1)
* // WITH cte_name AS (SELECT id AS column1 FROM table_a)
* $qb = $conn->createQueryBuilder()
* ->with('cte_name', 'SELECT 1 AS column1');
* ->with('cte_name', 'SELECT id AS column1 FROM table_a');
*
* // WITH cte_name(column1) AS (SELECT 1 AS column1)
* // WITH cte_name(column1) AS (SELECT id AS column1 FROM table_a)
* $qb = $conn->createQueryBuilder()
* ->with('cte_name', 'SELECT 1 AS column1', ['column1']);
* ->with('cte_name', 'SELECT id AS column1 FROM table_a', ['column1']);
* </code>
*
* @param string $name The name of the CTE
* @param string[] $columns The optional columns list to select in the CTE.
* @param string $name The name of the CTE
* @param string[]|null $columns The optional columns list to select in the CTE.
*
* @return $this This QueryBuilder instance.
*
* @throws QueryException Setting an empty array as columns is not allowed.
*/
public function with(string $name, string|QueryBuilder $part, array $columns = []): self
public function with(string $name, string|QueryBuilder $part, ?array $columns = null): self
{
$this->withParts[] = new With($name, $part, $columns);
if ($columns !== null && count($columns) === 0) {
throw new QueryException(sprintf('Columns defined in CTE "%s" should not be an empty array.', $name));
}

$this->commonTableExpressions[] = new CommonTableExpression($name, $part, $columns);

$this->sql = null;

Expand Down Expand Up @@ -1339,10 +1346,10 @@ private function getSQLForSelect(): string

$databasePlatform = $this->connection->getDatabasePlatform();
$selectParts = [];
if (count($this->withParts) > 0) {
if (count($this->commonTableExpressions) > 0) {
$selectParts[] = $databasePlatform
->createWithSQLBuilder()
->buildSQL(...$this->withParts);
->buildSQL(...$this->commonTableExpressions);
}

$selectParts[] = $databasePlatform
Expand Down
18 changes: 9 additions & 9 deletions src/SQL/Builder/WithSQLBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,28 +4,28 @@

namespace Doctrine\DBAL\SQL\Builder;

use Doctrine\DBAL\Query\With;
use Doctrine\DBAL\Query\CommonTableExpression;

use function array_merge;
use function count;
use function implode;

final class WithSQLBuilder
{
public function buildSQL(With $firstExpression, With ...$otherExpressions): string
public function buildSQL(CommonTableExpression $firstExpression, CommonTableExpression ...$otherExpressions): string
{
$withParts = [];
$cteParts = [];

foreach (array_merge([$firstExpression], $otherExpressions) as $part) {
$withPart = [$part->name];
if (count($part->columns) > 0) {
$withPart[] = '(' . implode(', ', $part->columns) . ')';
$ctePart = [$part->name];
if ($part->columns !== null && count($part->columns) > 0) {
$ctePart[] = '(' . implode(', ', $part->columns) . ')';
}

$withPart[] = ' AS (' . $part->query . ')';
$withParts[] = implode('', $withPart);
$ctePart[] = ' AS (' . $part->query . ')';
$cteParts[] = implode('', $ctePart);
}

return 'WITH ' . implode(', ', $withParts);
return 'WITH ' . implode(', ', $cteParts);
}
}
2 changes: 1 addition & 1 deletion tests/Functional/Query/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -417,7 +417,7 @@ public function testSelectWithCTEUnion(): void

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

$qb->with('cte_a', $subQueryBuilder3)
->select('id')
Expand Down
21 changes: 15 additions & 6 deletions tests/Query/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -855,19 +855,19 @@ public function testSelectAllWithoutTableAlias(): void

public function testSelectWithCTE(): void
{
$qbWith = new QueryBuilder($this->conn);
$qbWith->select('ta.id', 'ta.name', 'ta.table_b_id')
$cteQueryBuilder1 = new QueryBuilder($this->conn);
$cteQueryBuilder1->select('ta.id', 'ta.name', 'ta.table_b_id')
->from('table_a', 'ta')
->where('ta.name LIKE :name');

$qbAddWith = new QueryBuilder($this->conn);
$qbAddWith->select('ca.id AS virtual_id, ca.name AS virtual_name')
$cteQueryBuilder2 = new QueryBuilder($this->conn);
$cteQueryBuilder2->select('ca.id AS virtual_id, ca.name AS virtual_name')
->from('cte_a', 'ca')
->join('ca', 'table_b', 'tb', 'ca.table_b_id = tb.id');

$qb = new QueryBuilder($this->conn);
$qb->with('cte_a', $qbWith)
->with('cte_b', $qbAddWith, ['virtual_id', 'virtual_name'])
$qb->with('cte_a', $cteQueryBuilder1)
->with('cte_b', $cteQueryBuilder2, ['virtual_id', 'virtual_name'])
->select('cb.*')
->from('cte_b', 'cb');

Expand All @@ -881,6 +881,15 @@ public function testSelectWithCTE(): void
);
}

public function testSelectWithCTEAndEmptyColumns(): void
{
$this->expectException(QueryException::class);
$this->expectExceptionMessage('Columns defined in CTE "cte_a" should not be an empty array.');

$qb = new QueryBuilder($this->conn);
$qb->with('cte_a', 'SELECT 1 as id', []);
}

public function testGetParameterType(): void
{
$qb = new QueryBuilder($this->conn);
Expand Down

0 comments on commit c7e00a7

Please sign in to comment.