-
-
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.
Add rudimentary
UNION
support to the QueryBuilder
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
Showing
9 changed files
with
732 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
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -11,4 +11,6 @@ enum QueryType | |
case DELETE; | ||
case UPDATE; | ||
case INSERT; | ||
case UNION_ALL; | ||
case UNION_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,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; | ||
} | ||
} |
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,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; | ||
} | ||
} |
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.