-
-
Notifications
You must be signed in to change notification settings - Fork 1.3k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
| 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
Showing
12 changed files
with
618 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -11,4 +11,5 @@ enum QueryType | |
case DELETE; | ||
case UPDATE; | ||
case INSERT; | ||
case UNION; | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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, | ||
) { | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; | ||
} |
Oops, something went wrong.