diff --git a/typo3/sysext/core/Classes/Database/Query/ConcreteQueryBuilder.php b/typo3/sysext/core/Classes/Database/Query/ConcreteQueryBuilder.php index dbc4a2eee907..f1e3bf456d17 100644 --- a/typo3/sysext/core/Classes/Database/Query/ConcreteQueryBuilder.php +++ b/typo3/sysext/core/Classes/Database/Query/ConcreteQueryBuilder.php @@ -29,6 +29,8 @@ use Doctrine\DBAL\Query\QueryBuilder as DoctrineQueryBuilder; use Doctrine\DBAL\Query\QueryException; use Doctrine\DBAL\Query\QueryType; +use Doctrine\DBAL\Query\Union; +use Doctrine\DBAL\Query\UnionType; use TYPO3\CMS\Core\Database\Connection; /** @@ -113,6 +115,13 @@ class ConcreteQueryBuilder extends DoctrineQueryBuilder */ protected WithCollection $typo3_with; + /** + * The QueryBuilder for the union parts. + * + * @var Union[] + */ + protected array $typo3_unionParts = []; + /** * Initializes a new QueryBuilder. * @@ -146,6 +155,44 @@ public function __clone() } } + /** + * 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|ConcreteQueryBuilder|DoctrineQueryBuilder $part): self + { + parent::union($part); + $this->type = QueryType::UNION; + $this->typo3_unionParts = [new Union($part)]; + 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|ConcreteQueryBuilder|DoctrineQueryBuilder $part, UnionType $type = UnionType::DISTINCT): self + { + parent::addUnion($part, $type); + $this->type = QueryType::UNION; + $this->typo3_unionParts[] = new Union($part, $type); + return $this; + } + /** * Specifies an item that is to be returned in the query result. * Replaces any previously specified selections, if any. diff --git a/typo3/sysext/core/Classes/Database/Query/QueryBuilder.php b/typo3/sysext/core/Classes/Database/Query/QueryBuilder.php index 9a7bb879ec77..9ca45c711b0b 100644 --- a/typo3/sysext/core/Classes/Database/Query/QueryBuilder.php +++ b/typo3/sysext/core/Classes/Database/Query/QueryBuilder.php @@ -29,6 +29,7 @@ use Doctrine\DBAL\Query\Join; use Doctrine\DBAL\Query\QueryBuilder as DoctrineQueryBuilder; use Doctrine\DBAL\Query\QueryType; +use Doctrine\DBAL\Query\UnionType; use Doctrine\DBAL\Result; use Doctrine\DBAL\Statement; use Doctrine\DBAL\Types\StringType; @@ -455,6 +456,44 @@ protected function getCountExpression(string $column): string return 'COUNT(' . $column . ')'; } + /** + * Specifies union parts to be used to build a UNION query. + * Replaces any previously specified parts. + * + * ```php + * $qb = $conn->createQueryBuilder() + * ->union('SELECT 1 AS field1', 'SELECT 2 AS field1'); + * ``` + * + * @return $this + */ + public function union(string|QueryBuilder|ConcreteQueryBuilder|DoctrineQueryBuilder $part): QueryBuilder + { + $this->type = QueryType::UNION; + $concreteQueryBuilder = $this->getConcreteQueryBuilder(); + $concreteQueryBuilder->union($part); + return $this; + } + + /** + * Add parts to be used to build a UNION query. + * + * ```php + * $qb = $conn->createQueryBuilder() + * ->union('SELECT 1 AS field1') + * ->addUnion('SELECT 2 AS field1', 'SELECT 3 AS field1') + * ``` + * + * @return $this + */ + public function addUnion(string|QueryBuilder|ConcreteQueryBuilder|DoctrineQueryBuilder $part, UnionType $type = UnionType::DISTINCT): QueryBuilder + { + $this->type = QueryType::UNION; + $concreteQueryBuilder = $this->getConcreteQueryBuilder(); + $concreteQueryBuilder->addUnion($part, $type); + return $this; + } + /** * Specifies items that are to be returned in the query result. * Replaces any previously specified selections, if any. diff --git a/typo3/sysext/core/Documentation/Changelog/13.3/Feature-104631-AddUNIONClauseSupportToTheQueryBuilder.rst b/typo3/sysext/core/Documentation/Changelog/13.3/Feature-104631-AddUNIONClauseSupportToTheQueryBuilder.rst new file mode 100644 index 000000000000..dcfd6bd5673b --- /dev/null +++ b/typo3/sysext/core/Documentation/Changelog/13.3/Feature-104631-AddUNIONClauseSupportToTheQueryBuilder.rst @@ -0,0 +1,156 @@ +.. include:: /Includes.rst.txt + +.. _feature-104631-1723714985: + +================================================================= +Feature: #104631 - Add `UNION Clause` support to the QueryBuilder +================================================================= + +See :issue:`104631` + +Description +=========== + +The :sql:`UNION` clause is used to combine the result-set of two or more +:sql:`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: + +.. code-block:: sql + + SELECT column_name(s) FROM table1 + WHERE ... + + UNION + + SELECT column_name(s) FROM table2 + WHERE ... + + ORDER BY ... + LIMIT x OFFSET y + +with shared 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. + +Generic :sql:`UNION` clause support has been contributed to `Doctrine DBAL` and +is included since `Release 4.1.0 `__ +which introduces two new API method on the QueryBuilder: + +* :php:`union(string|QueryBuilder $part)` to create first UNION query part +* :php:`addUnion(string|QueryBuilder $part, UnionType $type = UnionType::DISTINCT)` + to add addtional :sql:`UNION (ALL|DISTINCT)` query parts with the selected union + query type. + +TYPO3 decorates the Doctrine DBAL QueryBuilder to provide for most API methods automatic +quoting of identifiers and values **and** to appliy database restrictions automatically +for :sql:`SELECT` queries. + +The Doctrine DBAL API has been adopted now to provide the same surface for the +TYPO3 :php:`\TYPO3\CMS\Core\Database\Query\QueryBuilder` and the intermediate +:php:`\TYPO3\CMS\Core\Database\Query\ConcreteQueryBuilder` to make it easier to +create :sql:`UNION` clause queries. The API on both methods allows to provide +dedicated QueryBuilder instances or direct queries as strings in case it is needed. + +.. note:: + + Providing :sql:`UNION` parts as plain string requires the developer to take + care of proper quoting and escaping within the query part. + +Another point worth to mention is, that only `named placeholder` can be used +and registered on the most outer :php:`QueryBuilder` object instance, similar +to advanced query creation using for example :sql:`SUB QUERIES`. + +.. warning:: + + :php:`QueryBuilder` can be used create :sql:`UNION` clause queries not + compatible with all database, for example using LIMIT/OFFSET in each + part query or other stuff. + +UnionType::DISTINCT and UnionType::ALL +~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ + +Each subsequent part needs to be defined either as :sql:`UNION DISTINCT` or +:sql:`UNION ALL` which could have not so obvious effects. + +For example, using :sql:`UNION ALL` for all parts in between except for the last +one would generate larger result sets first, but discards duplicates when adding +the last result set. On the other side, using :sql:`UNION ALL` tells the query +optimizer **not** to scan for duplicats and remove them at all which can be a +performance improvement - if you can deal with duplicates it can be ensured that +each part does not produce same outputs. + +Example: Compose a :sql:`UNION` clause query +~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ + +.. code-block:: php + :caption: Custom service class using an UNION query to retrieve data. + + use TYPO3\CMS\Core\Database\Connection; + use TYPO3\CMS\Core\Database\ConnectionPool; + use TYPO3\CMS\Core\Database\Query\QueryBuilder; + + final readonly MyService { + public function __construct( + private ConnectionPool $connectionPool, + ) {} + + public function executeUnionQuery( + int $pageIdOne, + int $pageIdTwo, + ): ?array { + $connection = $this->connectionPool->getConnectionForTable('pages'); + $unionQueryBuilder = $connection->createQueryBuilder(); + $firstPartQueryBuilder = $connection->createQueryBuilder(); + $firstPartQueryBuilder->getRestrictions()->removeAll(); + $secondPartQueryBuilder = $connection->createQueryBuilder(); + $secondPartQueryBuilder->getRestrictions()->removeAll(); + $expr = $unionQueryBuilder->expr(); + + $firstPartQueryBuilder + ->select('uid', 'pid', 'title') + ->from('pages') + ->where( + $expr->eq( + 'pages.uid', + $unionQueryBuilder->createNamedParameter($pageIdOne), + ); + $secondPartQueryBuilder + ->select('uid', 'pid', 'title') + ->from('pages') + ->where( + $expr->eq( + 'pages.uid', + $unionQueryBuilder->createNamedParameter($pageIdOne), + ); + + return $unionQueryBuilder + ->union($firstPartQueryBuilder) + ->addUnion($secondPartQueryBuilder, UnionType::DISTINCT) + ->orderBy('uid', 'ASC') + ->executeQuery() + ->fetchAllAssociative(); + } + } + +which would create following query for MySQL with :php:`$pageIdOne = 100` and +:php:`$pageIdTwo = 10`: + +.. code-block:: sql + + (SELECT `uid`, `pid`, `title` FROM pages WHERE `pages`.`uid` = 100) + UNION + (SELECT `uid`, `pid`, `title` FROM pages WHERE `pages`.`uid` = 10) + ORDER BY `uid` ASC + + +Impact +====== + +Extension authors can use the new :php:`QueryBuilder` methods to build more +advanced queries. + +.. index:: Database, PHP-API, ext:core diff --git a/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/Fixtures/DataSet/union-clause-simple.csv b/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/Fixtures/DataSet/union-clause-simple.csv new file mode 100644 index 000000000000..b5063b37faa2 --- /dev/null +++ b/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/Fixtures/DataSet/union-clause-simple.csv @@ -0,0 +1,6 @@ +"pages", +,"uid","pid","doktype","hidden","title", +,1,0,1,0,"page 1", +,2,0,254,0,"sysfolder 2", +,3,0,1,0,"page 3", +,4,0,254,0,"sysfolder 4", diff --git a/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/UnionClauseTest.php b/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/UnionClauseTest.php new file mode 100644 index 000000000000..04070b5d0e78 --- /dev/null +++ b/typo3/sysext/core/Tests/Functional/Database/Query/QueryBuilder/UnionClauseTest.php @@ -0,0 +1,304 @@ + 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 4, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 4'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_DEFAULT, + Connection::PARAM_INT + ) + ) + ); + $sysFolderPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $sysFolderPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_SYSFOLDER, + Connection::PARAM_INT + ) + ) + ); + $unionQueryBuilder + ->union($standardPagesQueryBuilder) + ->addUnion($sysFolderPagesQueryBuilder, UnionType::DISTINCT) + ->orderBy('doktype', 'ASC') + ->addOrderBy('uid', 'ASC'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function unionAllQueryWithAscendingOrderByUidReturnsExpectedResultSet(): void + { + $expectedRows = [ + ['uid' => 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 4, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 4'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_DEFAULT, + Connection::PARAM_INT + ) + ) + ); + $sysFolderPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $sysFolderPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_SYSFOLDER, + Connection::PARAM_INT + ) + ) + ); + $unionQueryBuilder + ->union($standardPagesQueryBuilder) + ->addUnion($sysFolderPagesQueryBuilder, UnionType::ALL) + ->orderBy('doktype', 'ASC') + ->addOrderBy('uid', 'ASC'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function unionDistinctQueryWithDescendingOrderByUidReturnsExpectedResult(): void + { + $expectedRows = [ + ['uid' => 4, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 4'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_DEFAULT, + Connection::PARAM_INT + ) + ) + ); + $sysFolderPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $sysFolderPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_SYSFOLDER, + Connection::PARAM_INT + ) + ) + ); + $unionQueryBuilder + ->union($standardPagesQueryBuilder) + ->addUnion($sysFolderPagesQueryBuilder, UnionType::DISTINCT) + ->orderBy('uid', 'desc'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function unionAllQueryWithDescendingOrderByUidReturnsExpectedResult(): void + { + $expectedRows = [ + ['uid' => 4, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 4'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_DEFAULT, + Connection::PARAM_INT + ) + ) + ); + $sysFolderPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $sysFolderPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_SYSFOLDER, + Connection::PARAM_INT + ) + ) + ); + $unionQueryBuilder + ->union($standardPagesQueryBuilder) + ->addUnion($sysFolderPagesQueryBuilder, UnionType::ALL) + ->orderBy('uid', 'desc'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function mixedStringAndQueryBuilderInstancesReturnsExpectedResultSet(): void + { + $expectedRows = [ + ['uid' => 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 4, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 4'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $standardPagesQueryBuilder + ->select('uid', 'pid', 'doktype', 'title') + ->from('pages') + ->where( + $unionQueryBuilder->expr()->eq( + 'doktype', + $unionQueryBuilder->createNamedParameter( + PageRepository::DOKTYPE_DEFAULT, + Connection::PARAM_INT + ) + ) + ); + $sysFolderPagesPlainSql = 'SELECT uid, pid, doktype, title FROM pages WHERE doktype = ' . PageRepository::DOKTYPE_SYSFOLDER; + $unionQueryBuilder + ->union($standardPagesQueryBuilder) + ->addUnion($sysFolderPagesPlainSql, UnionType::DISTINCT) + ->orderBy('doktype', 'ASC') + ->addOrderBy('uid', 'ASC'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function simpleValueListReturnsExpectedResultSet(): void + { + $expectedRows = [ + ['id' => 4, 'sorting' => 1], + ['id' => 3, 'sorting' => 2], + ['id' => 2, 'sorting' => 3], + ['id' => 1, 'sorting' => 4], + ]; + $platform = $this->getDefaultConnection()->getDatabasePlatform(); + $plainSelect1 = $platform->getDummySelectSQL('1 as id, 4 as sorting'); + $plainSelect2 = $platform->getDummySelectSQL('2 as id, 3 as sorting'); + $plainSelect3 = $platform->getDummySelectSQL('3 as id, 2 as sorting'); + $plainSelect4 = $platform->getDummySelectSQL('4 as id, 1 as sorting'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $unionQueryBuilder + ->union($plainSelect1) + ->addUnion($plainSelect3, UnionType::DISTINCT) + ->addUnion($plainSelect2, UnionType::DISTINCT) + ->addUnion($plainSelect4, UnionType::DISTINCT) + ->orderBy('sorting', 'ASC') + ->addOrderBy('id', 'ASC'); + self::assertSame($expectedRows, $unionQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + #[Test] + public function useSimpleValueListAsFromTableToEnsureSorting(): void + { + $expectedRows = [ + ['uid' => 2, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_SYSFOLDER, 'title' => 'sysfolder 2'], + ['uid' => 3, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 3'], + ['uid' => 1, 'pid' => 0, 'doktype' => PageRepository::DOKTYPE_DEFAULT, 'title' => 'page 1'], + ]; + $this->importCSVDataSet(__DIR__ . '/Fixtures/DataSet/union-clause-simple.csv'); + $platform = $this->getDefaultConnection()->getDatabasePlatform(); + $plainSelect1 = $platform->getDummySelectSQL('1 as id, 3 as sorting'); + $plainSelect2 = $platform->getDummySelectSQL('2 as id, 1 as sorting'); + $plainSelect3 = $platform->getDummySelectSQL('3 as id, 2 as sorting'); + $unionQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $unionQueryBuilder + ->union($plainSelect1) + ->addUnion($plainSelect3, UnionType::DISTINCT) + ->addUnion($plainSelect2, UnionType::ALL); + $pagesQueryBuilder = $this->getDefaultConnection()->createQueryBuilder(); + $pagesQueryBuilder->select('pages.uid', 'pages.pid', 'pages.doktype', 'pages.title')->from('pages') + ->getConcreteQueryBuilder() + ->innerJoin( + $pagesQueryBuilder->quoteIdentifier('pages'), + sprintf('(%s)', $unionQueryBuilder->getSQL()), + $pagesQueryBuilder->quoteIdentifier('value_list'), + sprintf( + '%s = %s', + $pagesQueryBuilder->quoteIdentifier('value_list.id'), + $pagesQueryBuilder->quoteIdentifier('pages.uid'), + ) + ); + $pagesQueryBuilder->orderBy('value_list.sorting', 'ASC')->addOrderBy('pages.uid'); + self::assertSame($expectedRows, $pagesQueryBuilder->executeQuery()->fetchAllAssociative()); + } + + private function getDefaultConnection(): Connection + { + return $this->getConnectionPool()->getConnectionByName(ConnectionPool::DEFAULT_CONNECTION_NAME); + } +} diff --git a/typo3/sysext/core/Tests/Unit/Database/Mocks/MockPlatform/MockPlatform.php b/typo3/sysext/core/Tests/Unit/Database/Mocks/MockPlatform/MockPlatform.php index 42b705870b24..553e64b26d65 100644 --- a/typo3/sysext/core/Tests/Unit/Database/Mocks/MockPlatform/MockPlatform.php +++ b/typo3/sysext/core/Tests/Unit/Database/Mocks/MockPlatform/MockPlatform.php @@ -233,4 +233,12 @@ public function quoteStringLiteral(string $str): string } return $quoteChar . str_replace($quoteChar, $quoteChar . $quoteChar, $str) . $quoteChar; } + + /** + * Returns the union select query part surrounded by parenthesis if possible for platform. + */ + public function getUnionSelectPartSQL(string $subQuery): string + { + return $subQuery; + } } diff --git a/typo3/sysext/core/Tests/Unit/Database/Query/QueryBuilderTest.php b/typo3/sysext/core/Tests/Unit/Database/Query/QueryBuilderTest.php index 169549c0ace0..342568bcee90 100644 --- a/typo3/sysext/core/Tests/Unit/Database/Query/QueryBuilderTest.php +++ b/typo3/sysext/core/Tests/Unit/Database/Query/QueryBuilderTest.php @@ -26,7 +26,9 @@ use Doctrine\DBAL\Platforms\SQLitePlatform as DoctrineSQLitePlatform; use Doctrine\DBAL\Query\From; use Doctrine\DBAL\Query\Join; +use Doctrine\DBAL\Query\QueryException; use Doctrine\DBAL\Query\QueryType; +use Doctrine\DBAL\Query\UnionType; use Doctrine\DBAL\Result; use Doctrine\DBAL\Types\Type; use PHPUnit\Framework\Attributes\DataProvider; @@ -65,6 +67,16 @@ protected function setUp(): void ); } + protected function tearDown(): void + { + unset( + $this->concreteQueryBuilder, + $this->connection, + $this->subject, + ); + parent::tearDown(); + } + #[Test] public function exprReturnsExpressionBuilderForConnection(): void { @@ -1325,4 +1337,90 @@ public function restrictionsAreAppliedInJoinConditionForRightJoins(): void $subject->executeQuery(); } + + #[Test] + public function unionWithOneUnionPartThrowException(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $queryBuilder = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $queryBuilder->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.', + ); + + $queryBuilder->getSQL(); + } + + #[Test] + public function unionAllReturnsUnionAllQuery(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $queryBuilder = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $queryBuilder + ->union('SELECT 1 AS field_one') + ->addUnion('SELECT 2 as field_one', UnionType::ALL); + + self::assertSame('SELECT 1 AS field_one UNION ALL SELECT 2 as field_one', $queryBuilder->getSQL()); + } + + #[Test] + public function unionAllAndLimitClauseReturnsUnionAllQuery(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $queryBuilder = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $queryBuilder + ->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', $queryBuilder->getSQL()); + } + + #[Test] + public function unionDistinctQueryReturnsUnionDistinctQuery(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $qb = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $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()); + } + + #[Test] + public function unionAllQueryWithOrderByReturnsUnionAllQueryWithOrderBy(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $queryBuilder = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $queryBuilder + ->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', $queryBuilder->getSQL()); + } + + #[Test] + public function unionDistinctQueryAndOrderByReturnsUnionQueryWithOrderBy(): void + { + $this->connection->method('getDatabasePlatform')->willReturn(new MockPlatform()); + $this->connection->method('quoteIdentifier')->willReturnCallback(fn($value) => '`' . $value . '`'); + $queryBuilder = new QueryBuilder($this->connection, null, new ConcreteQueryBuilder($this->connection)); + $queryBuilder + ->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', $queryBuilder->getSQL()); + } }