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 Apr 25, 2024
1 parent 5ec0376 commit 05f72d6
Show file tree
Hide file tree
Showing 9 changed files with 716 additions and 5 deletions.
62 changes: 57 additions & 5 deletions docs/en/reference/query-builder.rst
Expand Up @@ -51,7 +51,7 @@ Building a Query
----------------

The ``\Doctrine\DBAL\Query\QueryBuilder`` supports building ``SELECT``,
``INSERT``, ``UPDATE`` and ``DELETE`` queries. Which sort of query you
``INSERT``, ``UPDATE`` AND ``DELETE`` queries. Which sort of query you
are building depends on the methods you are using.

For ``SELECT`` queries you start with invoking the ``select()`` method
Expand Down Expand Up @@ -84,13 +84,10 @@ and ``delete($tableName)``:
->delete('users')
;
You can convert a query builder to its SQL string representation
by calling ``$queryBuilder->getSQL()`` or casting the object to string.

DISTINCT-Clause
~~~~~~~~~~~~~~~

The ``SELECT`` statement can be specified with a ``DISTINCT`` clause:
The ``SELECT`` and ``UNION``` statement can be specified with a ``DISTINCT`` clause:

.. code-block:: php
Expand All @@ -102,6 +99,11 @@ The ``SELECT`` statement can be specified with a ``DISTINCT`` clause:
->from('users')
;
$queryBuilder
->union('SELECT 1 AS field', 'SELECT 2 AS field')
->distinct()
;
WHERE-Clause
~~~~~~~~~~~~

Expand Down Expand Up @@ -315,6 +317,56 @@ 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)
;
You can convert a query builder to its SQL string representation
by calling ``$queryBuilder->getSQL()`` or casting the object to string.

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

Expand Down
7 changes: 7 additions & 0 deletions src/Platforms/AbstractPlatform.php
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
121 changes: 121 additions & 0 deletions src/Query/QueryBuilder.php
Expand Up @@ -153,6 +153,13 @@ class QueryBuilder
*/
private array $values = [];

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

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

Expand Down Expand Up @@ -501,6 +510,94 @@ 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 ...$parts): self
{
$this->type = QueryType::UNION_DISTINCT;

$this->union = $parts;

$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 ...$parts): self
{
$this->type = QueryType::UNION_DISTINCT;

$this->union = array_merge($this->union, $parts);

$this->sql = null;

return $this;
}

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

$this->union = $parts;

$this->sql = null;

return $this;
}

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

$this->union = array_merge($this->union, $parts);

$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 +1406,30 @@ private function getSQLForDelete(): string
return $query;
}

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

return $this->connection->getDatabasePlatform()
->createUnionSQLBuilder()
->buildSQL(
new UnionQuery(
$this->type === QueryType::UNION_DISTINCT,
$this->union,
$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
2 changes: 2 additions & 0 deletions src/Query/QueryType.php
Expand Up @@ -11,4 +11,6 @@ enum QueryType
case DELETE;
case UPDATE;
case INSERT;
case UNION_ALL;
case UNION_DISTINCT;
}
44 changes: 44 additions & 0 deletions src/Query/UnionQuery.php
@@ -0,0 +1,44 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\Query;

final class UnionQuery
{
/**
* @internal This class should be instantiated only by {@link QueryBuilder}.
*
* @param string[]|QueryBuilder[] $unionParts
* @param string[] $orderBy
*/
public function __construct(
private readonly bool $unionDistinct,
private readonly array $unionParts,
private readonly array $orderBy,
private readonly Limit $limit,
) {
}

public function isUnionDistinct(): bool
{
return $this->unionDistinct;
}

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

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

public function getLimit(): Limit
{
return $this->limit;
}
}
53 changes: 53 additions & 0 deletions src/SQL/Builder/DefaultUnionSQLBuilder.php
@@ -0,0 +1,53 @@
<?php

declare(strict_types=1);

namespace Doctrine\DBAL\SQL\Builder;

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

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 = [];
$modifier = $query->isUnionDistinct() ? ' UNION ' : ' UNION ALL ';
$unionParts = $this->prepareUnionParts($query);
$parts[] = implode($modifier, $unionParts);

$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;
}

/** @return string[] */
private function prepareUnionParts(UnionQuery $query): array
{
$return = [];
$unionParts = $query->getUnionParts();
foreach ($unionParts as $part) {
$return[] = (string) $part;
}

return $return;
}
}
14 changes: 14 additions & 0 deletions src/SQL/Builder/UnionSQLBuilder.php
@@ -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;
}

0 comments on commit 05f72d6

Please sign in to comment.