Skip to content

Commit

Permalink
Add QueryBuilder support for UNION clause (#6369)
Browse files Browse the repository at this point in the history
|      Q       |   A
|------------- | -----------
| Type         | feature
| Fixed issues | #6368

### Summary

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 parenthesis.

It is now possible to build `UNION` queries using
following additional QueryBuilder API methods:

* `union(string|QueryBuilder $part)` to create a `UNION`
   query retrieving unique rows
* `addUnion(string|QueryBuilder $part, UnionType $type)`
   to add `UNION (ALL|DISTINCT)` query with the selected
   union query type.

This follows the generic logic of `select(...)` and
`addSelect(...)` along with introducing new UnionType
enum and internal QueryType::UNION enum case.

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. Union SQL keyword and part
SQL generation is handled through added methods on the
Platforms to allow adjustment for furture versions if
needed - or throw a Exception if a Platform does not
support it anymore.

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)
   ->addUnion($select20, UnionType::ALL)
   ->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 authored Jun 14, 2024
1 parent 754e3ee commit ff0dab7
Show file tree
Hide file tree
Showing 12 changed files with 618 additions and 0 deletions.
53 changes: 53 additions & 0 deletions docs/en/reference/query-builder.rst
Original file line number Diff line number Diff line change
Expand Up @@ -315,6 +315,59 @@ 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(string|QueryBuilder $part)``
* ``addUnion(string|QueryBuilder $part, UnionType $type)``

.. code-block:: php
<?php
$queryBuilder
->union('SELECT 1 AS field')
->addUnion('SELECT 2 AS field', UnionType::DISTINCT)
->addUnion('SELECT 3 AS field', UnionType::DISTINCT)
->addUnion('SELECT 3 as field', UnionType::DISTINCT);
$queryBuilder
->union('SELECT 1 AS field')
->addUnion('SELECT 2 AS field', UnionType::ALL)
->addUnion('SELECT 3 AS field', UnionType::ALL)
->addUnion('SELECT 3 as field', UnionType::ALL);
$queryBuilder
->union('SELECT 1 AS field')
->addUnion('SELECT 2 AS field', UnionType::ALL)
->addUnion('SELECT 3 AS field', UnionType::ALL)
->addUnion('SELECT 3 as field', UnionType::DISTINCT);
$subQueryBuilder1
->select('id AS field')
->from('a_table');
$subQueryBuilder2
->select('id AS field')
->from('a_table');
$queryBuilder
->union($subQueryBuilder1)
->addUnion($subQueryBuilder2, UnionType::DISTINCT);
$subQueryBuilder1
->select('id AS field')
->from('a_table');
$subQueryBuilder2
->select('id AS field')
->from('a_table');
$queryBuilder
->union($subQueryBuilder1)
->addUnion($subQueryBuilder2,UnionType::ALL)
->orderBy('field', 'DESC')
->setMaxResults(100);
Building Expressions
--------------------

Expand Down
31 changes: 31 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,30 @@ public function columnsEqual(Column $column1, Column $column2): bool
return $column1->getComment() === $column2->getComment();
}

/**
* Returns the union select query part surrounded by parenthesis if possible for platform.
*/
public function getUnionSelectPartSQL(string $subQuery): string
{
return sprintf('(%s)', $subQuery);
}

/**
* Returns the `UNION ALL` keyword.
*/
public function getUnionAllSQL(): string
{
return 'UNION ALL';
}

/**
* Returns the compatible `UNION DISTINCT` keyword.
*/
public function getUnionDistinctSQL(): string
{
return 'UNION';
}

/**
* 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
8 changes: 8 additions & 0 deletions src/Platforms/SQLitePlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -991,4 +991,12 @@ public function createSchemaManager(Connection $connection): SQLiteSchemaManager
{
return new SQLiteSchemaManager($connection, $this);
}

/**
* Returns the union select query part surrounded by parenthesis if possible for platform.
*/
public function getUnionSelectPartSQL(string $subQuery): string
{
return $subQuery;
}
}
80 changes: 80 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,54 @@ 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;

if (count($this->unionParts) === 0) {
throw new QueryException('No initial UNION part set, use union() to set one first.');
}

$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 +1365,30 @@ 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) {
throw new QueryException(
'Insufficient UNION parts give, need at least 2.'
. ' Please use union() and addUnion() to set enough UNION parts.',
);
}

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,
) {
}
}
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
* @param string[] $orderBy
*/
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;
}
}
11 changes: 11 additions & 0 deletions src/Query/UnionType.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

enum UnionType
{
case ALL;
case DISTINCT;
}
48 changes: 48 additions & 0 deletions src/SQL/Builder/DefaultUnionSQLBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
<?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;

use function count;
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 !== null) {
$parts[] = $union->type === UnionType::ALL
? $this->platform->getUnionAllSQL()
: $this->platform->getUnionDistinctSQL();
}

$parts[] = $this->platform->getUnionSelectPartSQL((string) $union->query);
}

$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 ff0dab7

Please sign in to comment.