From ff0dab7827ce96824515eff4e43bbb0709c505eb Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Stefan=20B=C3=BCrk?= Date: Fri, 14 Jun 2024 13:35:30 +0200 Subject: [PATCH] Add `QueryBuilder` support for `UNION` clause (#6369) | 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 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 --- docs/en/reference/query-builder.rst | 53 +++++ src/Platforms/AbstractPlatform.php | 31 +++ src/Platforms/SQLitePlatform.php | 8 + src/Query/QueryBuilder.php | 80 +++++++ src/Query/QueryType.php | 1 + src/Query/Union.php | 15 ++ src/Query/UnionQuery.php | 38 +++ src/Query/UnionType.php | 11 + src/SQL/Builder/DefaultUnionSQLBuilder.php | 48 ++++ src/SQL/Builder/UnionSQLBuilder.php | 14 ++ tests/Functional/Query/QueryBuilderTest.php | 244 ++++++++++++++++++++ tests/Query/QueryBuilderTest.php | 75 ++++++ 12 files changed, 618 insertions(+) create mode 100644 src/Query/Union.php create mode 100644 src/Query/UnionQuery.php create mode 100644 src/Query/UnionType.php create mode 100644 src/SQL/Builder/DefaultUnionSQLBuilder.php create mode 100644 src/SQL/Builder/UnionSQLBuilder.php diff --git a/docs/en/reference/query-builder.rst b/docs/en/reference/query-builder.rst index b15a75f67ac..30b6ec642d7 100644 --- a/docs/en/reference/query-builder.rst +++ b/docs/en/reference/query-builder.rst @@ -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 + + 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 -------------------- diff --git a/src/Platforms/AbstractPlatform.php b/src/Platforms/AbstractPlatform.php index b9c5fa2d19d..c1612376ecf 100644 --- a/src/Platforms/AbstractPlatform.php +++ b/src/Platforms/AbstractPlatform.php @@ -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; @@ -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 * @@ -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. diff --git a/src/Platforms/SQLitePlatform.php b/src/Platforms/SQLitePlatform.php index 8ba836406d0..78e2465dd8c 100644 --- a/src/Platforms/SQLitePlatform.php +++ b/src/Platforms/SQLitePlatform.php @@ -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; + } } diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 9f4eb5a30a4..6141c6cc46b 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -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. */ @@ -336,6 +343,7 @@ public function getSQL(): string QueryType::DELETE => $this->getSQLForDelete(), QueryType::UPDATE => $this->getSQLForUpdate(), QueryType::SELECT => $this->getSQLForSelect(), + QueryType::UNION => $this->getSQLForUnion(), }; } @@ -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. + * + * + * $qb = $conn->createQueryBuilder() + * ->union('SELECT 1 AS field1', 'SELECT 2 AS field1'); + * + * + * @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. + * + * + * $qb = $conn->createQueryBuilder() + * ->union('SELECT 1 AS field1') + * ->addUnion('SELECT 2 AS field1', 'SELECT 3 AS field1') + * + * + * @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. @@ -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. diff --git a/src/Query/QueryType.php b/src/Query/QueryType.php index 632c4959fc9..9c15b32f72a 100644 --- a/src/Query/QueryType.php +++ b/src/Query/QueryType.php @@ -11,4 +11,5 @@ enum QueryType case DELETE; case UPDATE; case INSERT; + case UNION; } diff --git a/src/Query/Union.php b/src/Query/Union.php new file mode 100644 index 00000000000..4441924980c --- /dev/null +++ b/src/Query/Union.php @@ -0,0 +1,15 @@ +unionParts; + } + + /** @return string[] */ + public function getOrderBy(): array + { + return $this->orderBy; + } + + public function getLimit(): Limit + { + return $this->limit; + } +} diff --git a/src/Query/UnionType.php b/src/Query/UnionType.php new file mode 100644 index 00000000000..e7c0df69444 --- /dev/null +++ b/src/Query/UnionType.php @@ -0,0 +1,11 @@ +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; + } +} diff --git a/src/SQL/Builder/UnionSQLBuilder.php b/src/SQL/Builder/UnionSQLBuilder.php new file mode 100644 index 00000000000..271f035120d --- /dev/null +++ b/src/SQL/Builder/UnionSQLBuilder.php @@ -0,0 +1,14 @@ +executeQuery(); } + public function testUnionAllReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 1], ['field_one' => 1], ['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('2 as field_one')) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::ALL) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::ALL) + ->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 1], ['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('2 as field_one')) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::DISTINCT) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::DISTINCT) + ->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithDescOrderByReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 2], ['field_one' => 1]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('1 as field_one')) + ->addUnion($platform->getDummySelectSQL('2 as field_one'), UnionType::DISTINCT) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::DISTINCT) + ->orderBy('field_one', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAllWithLimitClauseReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('1 as field_one')) + ->addUnion($platform->getDummySelectSQL('2 as field_one'), UnionType::ALL) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::ALL) + ->setMaxResults(1) + ->setFirstResult(0) + ->orderBy('field_one', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithLimitClauseReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('1 as field_one')) + ->addUnion($platform->getDummySelectSQL('2 as field_one'), UnionType::DISTINCT) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::DISTINCT) + ->setMaxResults(1) + ->setFirstResult(0) + ->orderBy('field_one', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAllWithLimitAndOffsetClauseReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 1]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('1 as field_one')) + ->addUnion($platform->getDummySelectSQL('2 as field_one'), UnionType::ALL) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::ALL) + ->setMaxResults(1) + ->setFirstResult(1) + ->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithLimitAndOffsetClauseReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $plainSelect1 = $platform->getDummySelectSQL('1 as field_one'); + $plainSelect2 = $platform->getDummySelectSQL('2 as field_one'); + $plainSelect3 = $platform->getDummySelectSQL('1 as field_one'); + $qb = $this->connection->createQueryBuilder(); + $qb->union($platform->getDummySelectSQL('1 as field_one')) + ->addUnion($platform->getDummySelectSQL('2 as field_one'), UnionType::DISTINCT) + ->addUnion($platform->getDummySelectSQL('1 as field_one'), UnionType::DISTINCT) + ->setMaxResults(1) + ->setFirstResult(1) + ->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAllAndAddUnionAllWorksWithQueryBuilderPartsAndOrderByDescAndReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1], ['id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $subQueryBuilder1 = $this->connection->createQueryBuilder(); + $subQueryBuilder1->select('id')->from('for_update')->where($qb->expr()->eq('id', '1')); + + $subQueryBuilder2 = $this->connection->createQueryBuilder(); + $subQueryBuilder2->select('id')->from('for_update')->where($qb->expr()->eq('id', '2')); + + $subQueryBuilder3 = $this->connection->createQueryBuilder(); + $subQueryBuilder3->select('id')->from('for_update')->where($qb->expr()->eq('id', '1')); + + $qb->union($subQueryBuilder1) + ->addUnion($subQueryBuilder2, UnionType::ALL) + ->addUnion($subQueryBuilder3, UnionType::ALL) + ->orderBy('id', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAndAddUnionWithNamedParameterOnOuterInstanceAndOrderByDescWorks(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $subQueryBuilder1 = $this->connection->createQueryBuilder(); + $subQueryBuilder1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $subQueryBuilder2 = $this->connection->createQueryBuilder(); + $subQueryBuilder2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER))); + + $subQueryBuilder3 = $this->connection->createQueryBuilder(); + $subQueryBuilder3->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $qb->union($subQueryBuilder1) + ->addUnion($subQueryBuilder2, UnionType::DISTINCT) + ->addUnion($subQueryBuilder3, UnionType::DISTINCT) + ->orderBy('id', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAllAndAddUnionAllWorksWithQueryBuilderPartsAndReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 1], ['id' => 1], ['id' => 2]]); + $qb = $this->connection->createQueryBuilder(); + + $subQueryBuilder1 = $this->connection->createQueryBuilder(); + $subQueryBuilder1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $subQueryBuilder2 = $this->connection->createQueryBuilder(); + $subQueryBuilder2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER))); + + $subQueryBuilder3 = $this->connection->createQueryBuilder(); + $subQueryBuilder3->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $qb->union($subQueryBuilder1) + ->addUnion($subQueryBuilder2, UnionType::ALL) + ->addUnion($subQueryBuilder3, UnionType::ALL) + ->orderBy('id', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAndAddUnionWorksWithQueryBuilderPartsAndReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 1], ['id' => 2]]); + $qb = $this->connection->createQueryBuilder(); + + $subQueryBuilder1 = $this->connection->createQueryBuilder(); + $subQueryBuilder1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $subQueryBuilder2 = $this->connection->createQueryBuilder(); + $subQueryBuilder2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER))); + + $subQueryBuilder3 = $this->connection->createQueryBuilder(); + $subQueryBuilder3->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $qb->union($subQueryBuilder1) + ->addUnion($subQueryBuilder2, UnionType::DISTINCT) + ->addUnion($subQueryBuilder3, UnionType::DISTINCT) + ->orderBy('id', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + /** + * @param array> $rows + * + * @return array> + */ + private function prepareExpectedRows(array $rows): array + { + if (! TestUtil::isDriverOneOf('ibm_db2', 'pdo_oci', 'pdo_sqlsrv', 'oci8')) { + return $rows; + } + + if (! TestUtil::isDriverOneOf('ibm_db2')) { + foreach ($rows as &$row) { + foreach ($row as &$value) { + $value = (string) $value; + } + } + } + + if (! TestUtil::isDriverOneOf('ibm_db2', 'pdo_oci', 'oci8')) { + return $rows; + } + + foreach ($rows as &$row) { + $row = array_change_key_case($row, CASE_UPPER); + } + + return $rows; + } + private function platformSupportsSkipLocked(): bool { $platform = $this->connection->getDatabasePlatform(); diff --git a/tests/Query/QueryBuilderTest.php b/tests/Query/QueryBuilderTest.php index e56417938c7..096eb8d1e13 100644 --- a/tests/Query/QueryBuilderTest.php +++ b/tests/Query/QueryBuilderTest.php @@ -12,8 +12,10 @@ use Doctrine\DBAL\Query\Expression\ExpressionBuilder; use Doctrine\DBAL\Query\QueryBuilder; use Doctrine\DBAL\Query\QueryException; +use Doctrine\DBAL\Query\UnionType; use Doctrine\DBAL\Result; use Doctrine\DBAL\SQL\Builder\DefaultSelectSQLBuilder; +use Doctrine\DBAL\SQL\Builder\DefaultUnionSQLBuilder; use Doctrine\DBAL\Types\Types; use PHPUnit\Framework\Attributes\DataProvider; use PHPUnit\Framework\MockObject\MockObject; @@ -36,8 +38,16 @@ protected function setUp(): void ->willReturn($expressionBuilder); $platform = $this->createMock(AbstractPlatform::class); + $platform->method('getUnionSelectPartSQL') + ->willReturnArgument(0); + $platform->method('getUnionAllSQL') + ->willReturn('UNION ALL'); + $platform->method('getUnionDistinctSQL') + ->willReturn('UNION'); $platform->method('createSelectSQLBuilder') ->willReturn(new DefaultSelectSQLBuilder($platform, null, null)); + $platform->method('createUnionSQLBuilder') + ->willReturn(new DefaultUnionSQLBuilder($platform)); $this->conn->method('getDatabasePlatform') ->willReturn($platform); @@ -1409,4 +1419,69 @@ public function testExecuteStatement(): void $results, ); } + + public function testUnionOnlyThrowException(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one'); + + $this->expectException(QueryException::class); + $this->expectExceptionMessage( + 'Insufficient UNION parts give, need at least 2. ' + . 'Please use union() and addUnion() to set enough UNION parts.', + ); + + $qb->getSQL(); + } + + public function testUnionWAllAndLimitClauseReturnsUnionAllQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one') + ->addUnion('SELECT 2 as field_one', UnionType::ALL) + ->setMaxResults(10) + ->setFirstResult(10); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one LIMIT 10 OFFSET 10', $qb->getSQL()); + } + + public function testUnionAllWithOrderByReturnsUnionAllQueryWithOrderBy(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one') + ->addUnion('SELECT 2 as field_one', UnionType::ALL) + ->orderBy('field_one', 'ASC'); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one ORDER BY field_one ASC', $qb->getSQL()); + } + + public function testOnlyAddUnionThrowQueryException(): void + { + $this->expectException(QueryException::class); + + $qb = new QueryBuilder($this->conn); + $qb->addUnion('SELECT 1 AS field_one', UnionType::DISTINCT); + } + + public function testUnionAndAddUnionReturnsUnionQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one') + ->addUnion('SELECT 2 as field_one', UnionType::DISTINCT); + + self::assertSame('SELECT 1 AS field_one UNION SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionAndOrderByReturnsUnionQueryWithOrderBy(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one') + ->addUnion('SELECT 2 as field_one', UnionType::DISTINCT) + ->orderBy('field_one', 'ASC'); + + self::assertSame( + 'SELECT 1 AS field_one UNION SELECT 2 as field_one ORDER BY field_one ASC', + $qb->getSQL(), + ); + } }