Skip to content

Commit

Permalink
Add rudimentary UNION support to the QueryBuilder
Browse files Browse the repository at this point in the history
The `UNION` operator is used to combine the result-set
of two or more `SELECT` statements, which all database
vendors supports with usual specialities for each.

Still, there is a common shared subset which works for
all of them:

```
    SELECT column_name(s) FROM table1
    WHERE ...

    UNION <ALL | DISTINCT>

    SELECT column_name(s) FROM table2
    WHERE ...

    ORDER BY ...
    LIMIT x OFFSET y
```

with shared common requirements:

* Each `SELECT` must return the same fields
  in number, naming and order.

* Each `SELECT` **must not** have `ORDER BY`,
  expect MySQL allowing it to be used as sub
  query expression encapsulated in parentheses.

Taking the shared requirements and working behaviour,
it is possible to provide a generic support to the
QueryBuilder with a minimalistic surface addition now,
and following methods are added:

* `union(string|QueryBuilder ...$unionParts)` and
  `addUnion(string|QueryBuilder ...$unionParts)` to
   create a `UNION` query retrieving unique rows
* `unionAll(string|QueryBuilder ...$unionParts)` and
  `addUnionAll(string|QueryBuilder ...$unionParts) to
   create a `UNION ALL` query retrieving eventually
   duplicated rows.

This follows the generic logic as `select(...)` and
`addSelect(...)` along with introducing new internal
`QueryType::UNION_DISTINCT` and `QueryType::UNION_ALL`
enum cases.

Additional to the consideration to allow SQL strings
and QueryBuilder for `union()`, `unionAll(), `addUnion()`
and `addUnionAll()` and minimize the direct handling
of miss-configuration to the number of provided parts
and let other issues like the field (order, count, naming)
or not allowed order by handling to the database itself.
With that, vendor specific implementation can be done if
required.

Technically, the SQL build process is dispatched to a
`DefaultUnionSQLBuilder` along with an `UnionSQLBuilder`
interface, which also allows application to implement
custom behaviour if required.

Example:

```php
$platform = $connection->getDatabasePlatform();
$qb       = $>connection->createQueryBuilder();
$select10 = $platform->getDummySelectSQL('2 as field_one');
$select20 = $platform->getDummySelectSQL('1 as field_one');
$qb->union($select10,    /*$select11, $select12, ... */)
   ->addUnion($select20, /*$select21, $select22, ... */)
   ->setMaxResults(1)
   ->setFirstResult(1)
   ->orderBy('field_one', 'ASC');
$rows = $qb->executeQuery()->fetchAllAssociative();
```

Unit and functional tests are added to demonstrate the
implementation and cover it for future changes.

Resolves: #6368
  • Loading branch information
sbuerk committed Jun 12, 2024
1 parent 754e3ee commit a6dd58f
Show file tree
Hide file tree
Showing 11 changed files with 707 additions and 0 deletions.
47 changes: 47 additions & 0 deletions docs/en/reference/query-builder.rst
Original file line number Diff line number Diff line change
Expand Up @@ -315,6 +315,53 @@ user-input:
->setParameter(0, $userInputLastLogin)
;
UNION-Clause
~~~~~~~~~~~~

To combine multiple ``SELECT`` queries into one result-set you can pass SQL Part strings
or QueryBuilder instances to one of the following methods:

* ``union('SELECT 1 as field', $partQueryBuilder)``
* ``addUnion('SELECT 1 as field', $partQueryBuilder)``
* ``unionAll('SELECT 1 as field', $partQueryBuilder)``
* ``addUnionAll('SELECT 1 as field', $partQueryBuilder)``

.. code-block:: php
<?php
$queryBuilder
->union('SELECT 1 AS field', 'SELECT 2 AS field')
->addUnion('SELECT 3 AS field', 'SELECT 3 as field')
;
$queryBuilder
->unionAll('SELECT 1 AS field', 'SELECT 2 AS field')
->addUnionAll('SELECT 3 AS field', 'SELECT 3 as field')
;
$subQueryBuilder1
->select('id AS field')
->from('a_table');
$subQueryBuilder2
->select('id AS field')
->from('a_table');
$queryBuilder
->union($subQueryBuilder1)
->addUnion($subQueryBuilder2)
;
$subQueryBuilder1
->select('id AS field')
->from('a_table');
$subQueryBuilder2
->select('id AS field')
->from('a_table');
$queryBuilder
->unionAll($subQueryBuilder1)
->addUnionAll($subQueryBuilder2)
;
Building Expressions
--------------------

Expand Down
12 changes: 12 additions & 0 deletions src/Platforms/AbstractPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,9 @@
use Doctrine\DBAL\Schema\TableDiff;
use Doctrine\DBAL\Schema\UniqueConstraint;
use Doctrine\DBAL\SQL\Builder\DefaultSelectSQLBuilder;
use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder;
use Doctrine\DBAL\SQL\Builder\SelectSQLBuilder;
use Doctrine\DBAL\SQL\Builder\UnionSQLBuilder;
use Doctrine\DBAL\SQL\Parser;
use Doctrine\DBAL\TransactionIsolationLevel;
use Doctrine\DBAL\Types;
Expand Down Expand Up @@ -770,6 +772,11 @@ public function createSelectSQLBuilder(): SelectSQLBuilder
return new DefaultSelectSQLBuilder($this, 'FOR UPDATE', 'SKIP LOCKED');
}

public function createUnionSQLBuilder(): UnionSQLBuilder
{
return new DefaultUnionSQLBuilder($this);
}

/**
* @internal
*
Expand Down Expand Up @@ -2210,6 +2217,11 @@ public function columnsEqual(Column $column1, Column $column2): bool
return $column1->getComment() === $column2->getComment();
}

public function getUnionPartSQL(string $subQuery): string
{
return sprintf('(%s)', $subQuery);
}

/**
* Creates the schema manager that can be used to inspect and change the underlying
* database schema according to the dialect of the platform.
Expand Down
77 changes: 77 additions & 0 deletions src/Query/QueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,13 @@ class QueryBuilder
*/
private array $values = [];

/**
* The QueryBuilder for the union parts.
*
* @var Union[]
*/
private array $unionParts = [];

/**
* The query cache profile used for caching results.
*/
Expand Down Expand Up @@ -336,6 +343,7 @@ public function getSQL(): string
QueryType::DELETE => $this->getSQLForDelete(),
QueryType::UPDATE => $this->getSQLForUpdate(),
QueryType::SELECT => $this->getSQLForSelect(),
QueryType::UNION => $this->getSQLForUnion(),
};
}

Expand Down Expand Up @@ -501,6 +509,50 @@ public function forUpdate(ConflictResolutionMode $conflictResolutionMode = Confl
return $this;
}

/**
* Specifies union parts to be used to build a UNION query.
* Replaces any previously specified parts.
*
* <code>
* $qb = $conn->createQueryBuilder()
* ->union('SELECT 1 AS field1', 'SELECT 2 AS field1');
* </code>
*
* @return $this
*/
public function union(string|QueryBuilder $part): self
{
$this->type = QueryType::UNION;

$this->unionParts = [new Union($part)];

$this->sql = null;

return $this;
}

/**
* Add parts to be used to build a UNION query.
*
* <code>
* $qb = $conn->createQueryBuilder()
* ->union('SELECT 1 AS field1')
* ->addUnion('SELECT 2 AS field1', 'SELECT 3 AS field1')
* </code>
*
* @return $this
*/
public function addUnion(string|QueryBuilder $part, UnionType $type): self
{
$this->type = QueryType::UNION;

$this->unionParts[] = new Union($part, $type);

$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 @@ -1309,6 +1361,31 @@ private function getSQLForDelete(): string
return $query;
}

/**
* Converts this instance into a UNION string in SQL.
*/
private function getSQLForUnion(): string
{
$countUnions = count($this->unionParts);
if ($countUnions < 2) {
$message = $countUnions === 0
? 'No UNION parts given. Please use union(), unionAll, addUnion or addUnionAll().'
: 'Insufficient UNION parts give, need at least 2. Please use addUnion() or addUnionAll() to add more.';

throw new QueryException($message);
}

return $this->connection->getDatabasePlatform()
->createUnionSQLBuilder()
->buildSQL(
new UnionQuery(
$this->unionParts,
$this->orderBy,
new Limit($this->maxResults, $this->firstResult),
),
);
}

/**
* Gets a string representation of this QueryBuilder which corresponds to
* the final SQL query being constructed.
Expand Down
1 change: 1 addition & 0 deletions src/Query/QueryType.php
Original file line number Diff line number Diff line change
Expand Up @@ -11,4 +11,5 @@ enum QueryType
case DELETE;
case UPDATE;
case INSERT;
case UNION;
}
15 changes: 15 additions & 0 deletions src/Query/Union.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

/** @internal */
final class Union
{
public function __construct(
public readonly string|QueryBuilder $query,
public readonly ?UnionType $type = null,

Check failure on line 12 in src/Query/Union.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 1 space between type hint and argument "$type"; 10 found

Check failure on line 12 in src/Query/Union.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

There must be exactly one space between parameter type hint and parameter $type.

Check failure on line 12 in src/Query/Union.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

There must be exactly one space between type hint and property $type.
) {
}
}

Check failure on line 15 in src/Query/Union.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 1 newline at end of file; 0 found
38 changes: 38 additions & 0 deletions src/Query/UnionQuery.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

final class UnionQuery
{
/**
* @internal This class should be instantiated only by {@link QueryBuilder}.
*
* @param Union[] $unionParts

Check failure on line 12 in src/Query/UnionQuery.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 2 spaces after parameter type; 3 found
* @param string[] $orderBy

Check failure on line 13 in src/Query/UnionQuery.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 1 spaces after parameter type; 2 found
*/
public function __construct(
private readonly array $unionParts,
private readonly array $orderBy,
private readonly Limit $limit,
) {
}

/** @return Union[] */
public function getUnionParts(): array
{
return $this->unionParts;
}

/** @return string[] */
public function getOrderBy(): array
{
return $this->orderBy;
}

public function getLimit(): Limit
{
return $this->limit;
}
}
12 changes: 12 additions & 0 deletions src/Query/UnionType.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

/** @internal */
enum UnionType
{
case ALL;
case DISTINCT;
}

Check failure on line 12 in src/Query/UnionType.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 1 newline at end of file; 0 found
49 changes: 49 additions & 0 deletions src/SQL/Builder/DefaultUnionSQLBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\SQL\Builder;

use Doctrine\DBAL\Platforms\AbstractPlatform;
use Doctrine\DBAL\Query\UnionQuery;

use Doctrine\DBAL\Query\UnionType;

Check failure on line 10 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 0 lines between same types of use statement, found 1.
use function count;

Check failure on line 11 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Coding Standards / Coding Standards (8.3)

Expected 1 line between different types of use statement, found 0.
use function implode;

final class DefaultUnionSQLBuilder implements UnionSQLBuilder
{
public function __construct(
private readonly AbstractPlatform $platform,
) {
}

public function buildSQL(UnionQuery $query): string
{
$parts = [];
foreach ($query->getUnionParts() as $union) {
if ($union->type !== []) {

Check failure on line 25 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Static Analysis with Psalm (8.3)

RedundantCondition

src/SQL/Builder/DefaultUnionSQLBuilder.php:25:17: RedundantCondition: Doctrine\DBAL\Query\UnionType|null can never contain null (see https://psalm.dev/122)
$parts[] = match ($union->type) {

Check failure on line 26 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Static Analysis with PHPStan (8.3)

Match expression does not handle remaining value: null
UnionType::ALL => 'UNION ALL',
UnionType::DISTINCT => 'UNION',
};
}

$parts[] = $this->platform->getUnionPartSQL($union->query);

Check failure on line 32 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Static Analysis with PHPStan (8.3)

Parameter #1 $subQuery of method Doctrine\DBAL\Platforms\AbstractPlatform::getUnionPartSQL() expects string, Doctrine\DBAL\Query\QueryBuilder|string given.

Check failure on line 32 in src/SQL/Builder/DefaultUnionSQLBuilder.php

View workflow job for this annotation

GitHub Actions / Static Analysis with Psalm (8.3)

PossiblyInvalidArgument

src/SQL/Builder/DefaultUnionSQLBuilder.php:32:57: PossiblyInvalidArgument: Argument 1 of Doctrine\DBAL\Platforms\AbstractPlatform::getUnionPartSQL expects string, but possibly different type Doctrine\DBAL\Query\QueryBuilder|string provided (see https://psalm.dev/092)
}

$orderBy = $query->getOrderBy();
if (count($orderBy) > 0) {
$parts[] = 'ORDER BY ' . implode(', ', $orderBy);
}

$sql = implode(' ', $parts);
$limit = $query->getLimit();

if ($limit->isDefined()) {
$sql = $this->platform->modifyLimitQuery($sql, $limit->getMaxResults(), $limit->getFirstResult());
}

return $sql;
}
}
14 changes: 14 additions & 0 deletions src/SQL/Builder/UnionSQLBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\SQL\Builder;

use Doctrine\DBAL\Exception;
use Doctrine\DBAL\Query\UnionQuery;

interface UnionSQLBuilder
{
/** @throws Exception */
public function buildSQL(UnionQuery $query): string;
}
Loading

0 comments on commit a6dd58f

Please sign in to comment.