From d1f6bc8e8209ecd3e58bccecbd721f396a14028b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Stefan=20B=C3=BCrk?= Date: Wed, 24 Apr 2024 12:21:17 +0200 Subject: [PATCH] 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 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 by adding `union(...)` and `addUnion(...)` methods following the same logic as `select(...)` and `addSelect(...)` along with introducing a new internal `QueryType::UNION`. To avoid to much noise, the `distinct()` method and property is reused to controll the distinctness of the build union query. `UNION DISTICT` is the default and the same `UNION`, which means that without using `QueryBuilder::distinct()` duplicated rows may be returned. It has been consodered to reuse distinct over adding a additional `union distict / unique rows) property and method to controll that switch, albeit reverting the default. Additional consideration has been, to allow SQL strings and QueryBuilder for `union()` and `addUnion()` and to minimize the direct handling of miss-configuration to the number (minimum of two union 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(); ``` This change ... * adds internal `QueryType::UNION` enum case. * adds `UnionSQLBuilder interface` and implement `DefaultUnionSQLBuilder`. * adds `AbstractPlatform::createUnionSQLBuilder()`. * adds public QueryBuilder methods `QueryBuilder::union()`, `QueryBuilder::addUnion()` and `QueryBuilder::uniqueRows()`. * modifies `QueryBuilder::getSQL()` to build a UNION string, handled with private method `QueryBuilder::getUnionSQLString()`. * adds unit and functional tests. * modifies existing QueryBuilder documentation file. Resolves #6368 --- docs/en/reference/query-builder.rst | 35 +++- src/Platforms/AbstractPlatform.php | 7 + src/Query/QueryBuilder.php | 77 +++++++ src/Query/QueryType.php | 1 + src/Query/UnionQuery.php | 44 ++++ src/SQL/Builder/DefaultUnionSQLBuilder.php | 53 +++++ src/SQL/Builder/UnionSQLBuilder.php | 14 ++ tests/Functional/Query/QueryBuilderTest.php | 220 ++++++++++++++++++++ tests/Query/QueryBuilderTest.php | 99 +++++++++ 9 files changed, 547 insertions(+), 3 deletions(-) create mode 100644 src/Query/UnionQuery.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..dd5ba24284b 100644 --- a/docs/en/reference/query-builder.rst +++ b/docs/en/reference/query-builder.rst @@ -51,8 +51,8 @@ Building a Query ---------------- The ``\Doctrine\DBAL\Query\QueryBuilder`` supports building ``SELECT``, -``INSERT``, ``UPDATE`` and ``DELETE`` queries. Which sort of query you -are building depends on the methods you are using. +``INSERT``, ``UPDATE``, ``DELETE`` and ``UNION`` 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 @@ -84,13 +84,37 @@ and ``delete($tableName)``: ->delete('users') ; +For ``UNION`` queries you can pass SQL Part strings or QueryBuilder +instances to ``union('SELECT 1 as field', $partQueryBuilder)`` or +``addUnion('SELECT 1 as field', $partQueryBuilder)``: + +.. code-block:: php + + union('SELECT 1 AS field', 'SELECT 2 AS field') + ->addUnion('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) + ->addUnionBuilder($subQueryBuilder2) + ; + 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 @@ -102,6 +126,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 ~~~~~~~~~~~~ diff --git a/src/Platforms/AbstractPlatform.php b/src/Platforms/AbstractPlatform.php index 0beb37a0939..6e35ef8f146 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 * diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 1127c6b9e4a..6a778a315c9 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -22,6 +22,7 @@ use function array_keys; use function array_merge; use function array_unshift; +use function array_values; use function count; use function implode; use function is_object; @@ -153,6 +154,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. */ @@ -336,6 +344,7 @@ public function getSQL(): string QueryType::DELETE => $this->getSQLForDelete(), QueryType::UPDATE => $this->getSQLForUpdate(), QueryType::SELECT => $this->getSQLForSelect(), + QueryType::UNION => $this->getSQLForUnion(), }; } @@ -501,6 +510,50 @@ 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 ...$parts): self + { + $this->type = QueryType::UNION; + + $this->union = $parts; + + $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 ...$parts): self + { + $this->type = QueryType::UNION; + + $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. @@ -1309,6 +1362,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->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. 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/UnionQuery.php b/src/Query/UnionQuery.php new file mode 100644 index 00000000000..deeaddac148 --- /dev/null +++ b/src/Query/UnionQuery.php @@ -0,0 +1,44 @@ +distinct; + } + + /** @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; + } +} diff --git a/src/SQL/Builder/DefaultUnionSQLBuilder.php b/src/SQL/Builder/DefaultUnionSQLBuilder.php new file mode 100644 index 00000000000..ccadc5e8cb9 --- /dev/null +++ b/src/SQL/Builder/DefaultUnionSQLBuilder.php @@ -0,0 +1,53 @@ +isDistinct() ? ' 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; + } +} 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 testUnionWithoutDistinctReturnsExpectedResult(): 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'), + $platform->getDummySelectSQL('1 as field_one'), + )->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testOnlyAddUnionWithoutDistinctReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 1], ['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->addUnion( + $platform->getDummySelectSQL('2 as field_one'), + $platform->getDummySelectSQL('1 as field_one'), + )->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAndAddUniontWithoutDistinctReturnsExpectedResult(): 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')) + ->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'), + $platform->getDummySelectSQL('2 as field_one'), + )->orderBy('field_one', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithDistinctReturnsExpectedResult(): 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'), + $platform->getDummySelectSQL('1 as field_one'), + )->distinct()->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testOnlyAddUnionWithDistinctReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 1], ['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->addUnion( + $platform->getDummySelectSQL('2 as field_one'), + $platform->getDummySelectSQL('1 as field_one'), + )->distinct()->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionAndAddUnionWithDistinctReturnsExpectedResult(): 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')) + ->distinct() + ->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithDistinctAndDescOrderByReturnsExpectedResult(): 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'), + $platform->getDummySelectSQL('2 as field_one'), + )->distinct()->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('2 as field_one'), + $platform->getDummySelectSQL('1 as field_one'), + )->setMaxResults(1)->setFirstResult(0)->orderBy('field_one', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithLimitAndOffsetClauseReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['field_one' => 2]]); + $platform = $this->connection->getDatabasePlatform(); + $qb = $this->connection->createQueryBuilder(); + $qb->union( + $platform->getDummySelectSQL('2 as field_one'), + $platform->getDummySelectSQL('1 as field_one'), + )->setMaxResults(1)->setFirstResult(1)->orderBy('field_one', 'ASC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWorksWithQueryBuilerPartsAndOrderByDescAndReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $sub1 = $this->connection->createQueryBuilder(); + $sub1->select('id')->from('for_update')->where($qb->expr()->eq('id', '2')); + + $sub2 = $this->connection->createQueryBuilder(); + $sub2->select('id')->from('for_update')->where($qb->expr()->eq('id', '1')); + + $qb = $qb->union($sub1)->addUnion($sub2)->orderBy('id', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWithNamedParameterOnOuterInstanceAndOrderByDescWorks(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 2], ['id' => 1]]); + $qb = $this->connection->createQueryBuilder(); + + $sub1 = $this->connection->createQueryBuilder(); + $sub1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER))); + + $sub2 = $this->connection->createQueryBuilder(); + $sub2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $qb = $qb->union($sub1)->addUnion($sub2)->orderBy('id', 'DESC'); + + self::assertSame($expectedRows, $qb->executeQuery()->fetchAllAssociative()); + } + + public function testUnionWorksWithQueryBuilderPartsAndReturnsExpectedResult(): void + { + $expectedRows = $this->prepareExpectedRows([['id' => 1], ['id' => 2]]); + $qb = $this->connection->createQueryBuilder(); + + $sub1 = $this->connection->createQueryBuilder(); + $sub1->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(2, ParameterType::INTEGER))); + + $sub2 = $this->connection->createQueryBuilder(); + $sub2->select('id') + ->from('for_update') + ->where($qb->expr()->eq('id', $qb->createNamedParameter(1, ParameterType::INTEGER))); + + $qb = $qb->union($sub1)->addUnion($sub2)->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..7527188c2a4 100644 --- a/tests/Query/QueryBuilderTest.php +++ b/tests/Query/QueryBuilderTest.php @@ -14,6 +14,7 @@ use Doctrine\DBAL\Query\QueryException; 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; @@ -38,6 +39,8 @@ protected function setUp(): void $platform = $this->createMock(AbstractPlatform::class); $platform->method('createSelectSQLBuilder') ->willReturn(new DefaultSelectSQLBuilder($platform, null, null)); + $platform->method('createUnionSQLBuilder') + ->willReturn(new DefaultUnionSQLBuilder($platform)); $this->conn->method('getDatabasePlatform') ->willReturn($platform); @@ -1409,4 +1412,100 @@ public function testExecuteStatement(): void $results, ); } + + public function testUnionWithNoUnionPartsThrowException(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union(); + + $this->expectException(QueryException::class); + $this->expectExceptionMessage('No UNION parts given. Please use union() or addUnion().'); + + $qb->getSQL(); + } + + public function testUnionWithOneUnionPartThrowException(): 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 addUnion() to add more.', + ); + + $qb->getSQL(); + } + + public function testUnionWithoutDistinctReturnsUnionAllQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one', 'SELECT 2 as field_one'); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionWithoutDistinctAndLimitClauseReturnsUnionAllQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one', 'SELECT 2 as field_one')->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 testOnlyAddUnionWithoutDistinctReturnsUnionAllQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->addUnion('SELECT 1 AS field_one', 'SELECT 2 as field_one'); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionAndAddUniontWithoutDistinctReturnsUnionAllQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one')->addUnion('SELECT 2 as field_one'); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionWithOrderByReturnsUnionAllQueryWithOrderBy(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one', 'SELECT 2 as field_one')->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 testUnionWithDistinctReturnsUnionQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one', 'SELECT 2 as field_one')->distinct(); + + self::assertSame('SELECT 1 AS field_one UNION SELECT 2 as field_one', $qb->getSQL()); + } + + public function testOnlyAddUnionWithDistinctReturnsUnionQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->addUnion('SELECT 1 AS field_one', 'SELECT 2 as field_one')->distinct(); + + self::assertSame('SELECT 1 AS field_one UNION SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionAndAddUnionWithDistinctReturnsUnionQuery(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one')->addUnion('SELECT 2 as field_one')->distinct(); + + self::assertSame('SELECT 1 AS field_one UNION SELECT 2 as field_one', $qb->getSQL()); + } + + public function testUnionWithDistinctAndOrderByReturnsUnionQueryWithOrderBy(): void + { + $qb = new QueryBuilder($this->conn); + $qb->union('SELECT 1 AS field_one', 'SELECT 2 as field_one')->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()); + } }