Skip to content

[FEATURE] Add UNION Clause support to the QueryBuilder #5349

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 6 commits into from
Feb 18, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
80 changes: 80 additions & 0 deletions Documentation/ApiOverview/Database/QueryBuilder/Index.rst
Original file line number Diff line number Diff line change
Expand Up @@ -847,6 +847,86 @@ Remarks:
* For more complex statements you can use the raw Doctrine QueryBuilder.
See remarks for :ref:`orderBy() <database-query-builder-orderby>`

.. _database-query-builder-union:

union() and addUnion()
======================

Method `union()` provides a streamlined way to combine result sets from multiple
queries.

:php:`union(string|QueryBuilder $part)`
Creates the initial :sql:`UNION` query part by accepting either a raw SQL
string or a `QueryBuilder` instance. Calling `union()` resets all previous
union definitions, it should therefore only be called once, using `addUnion()`
to add subsequent union parts.

:php:`addUnion(string|QueryBuilder $part, UnionType $type = UnionType::DISTINCT)`
Adds additional :sql:`UNION` parts to the query. The `$type` parameter accepts:

`UnionType::DISTINCT`
Combines results while eliminating duplicates.
`UnionType::ALL`
Combines results and retains all duplicates. Not removing duplicates can
be a performance improvement.

.. note::
While technically possible, it is not recommended to send direct SQL queries
as strings to the `union()` and `addUnion()` methods. We recommend to use a
query builder.

If you decide to do so you **must** take care of quoting, escaping, and
valid SQL Syntax for the database system in question. The `Default Restrictions <https://docs.typo3.org/permalink/t3coreapi:database-query-builder-select-restrictions>`_
are **not applied** on that part.

Named placeholders, such as created by :php:`QueryBuilder::createNamedParameter()`
**must** be created on the outer most QueryBuilder See the example below.

.. seealso::
* `W3School: SQL UNION Operator <https://www.w3schools.com/sql/sql_union.asp>`_
* For technical details see the changelog entry `Feature: #104631 - Add
UNION Clause support to the QueryBuilder <https://docs.typo3.org/permalink/changelog:feature-104631-1723714985>`_.

.. _database-query-builder-union-db-support:

Database provider support of union() and addUnion()
---------------------------------------------------

:php-short:`\TYPO3\CMS\Core\Database\Query\QueryBuilder` can be used create
:sql:`UNION` clause queries not compatible with all database providers,
for example using :sql:`LIMIT/OFFSET` in each part query or other stuff.

When building functional tests, run them on all database types that should
be supported.

.. _database-query-builder-union-example-querybuilder:

Example using `union()` on two QueryBuilders
--------------------------------------------

.. literalinclude:: _UnionExample.php
:caption: packages/my_extension/classes/Service/MyService.php

Line 18
All query parts **must** share the same connection.
Line 19
The outer most QueryBuilder is responsible for the union, it **must** be
used to create named parameters and build expressions within the sub queries.
Line 22-23
We therefore pass the central QueryBuilder responsible for the :sql:`UNION`
to all subqueries. Same with the ExpressionBuilder.
Line 25-30
We start building the `union()` on the first sub query, then add the
second sub query using `addUnion()`
Line 41
Only use the ExpressionBuilder of the sql:`UNION` within the subqueries.
Line 50
Named parameters must also be called on the outer most union query builder.

The `Default Restrictions <https://docs.typo3.org/permalink/t3coreapi:database-query-builder-select-restrictions>`_
are applied to each subquery automatically.

.. _database-query-builder-setMaxResults:

setMaxResults() and setFirstResult()
====================================
Expand Down
80 changes: 80 additions & 0 deletions Documentation/ApiOverview/Database/QueryBuilder/_UnionExample.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
<?php

namespace MyExtension\MyVendor\Service;

use Doctrine\DBAL\Query\UnionType;
use TYPO3\CMS\Core\Database\Connection;
use TYPO3\CMS\Core\Database\ConnectionPool;
use TYPO3\CMS\Core\Database\Query\QueryBuilder;

final readonly class MyService
{
public function __construct(
private ConnectionPool $connectionPool,
) {}

public function getTitlesOfSubpagesAndContent(
int $parentId,
): ?array {
$connection = $this->connectionPool->getConnectionForTable('pages');
$unionQueryBuilder = $connection->createQueryBuilder();

// Passing the outermost QueryBuilder to the subqueries
$firstPartQueryBuilder = $this->getUnionPart1QueryBuilder($connection, $unionQueryBuilder, $parentId);
$secondPartQueryBuilder = $this->getUnionPart2QueryBuilder($connection, $unionQueryBuilder, $parentId);

return $unionQueryBuilder
->union($firstPartQueryBuilder)
->addUnion($secondPartQueryBuilder, UnionType::DISTINCT)
->orderBy('uid', 'ASC')
->executeQuery()
->fetchAllAssociative();
}

private function getUnionPart1QueryBuilder(
Connection $connection,
QueryBuilder $unionQueryBuilder,
int $pageId,
): QueryBuilder {
$queryBuilder = $connection->createQueryBuilder();
// The union Expression Builder **must** be used on subqueries
$unionExpr = $unionQueryBuilder->expr();
$queryBuilder
// The column names of the first query are used
// The column count of both subqueries must be the same
// The data types must be compatible across columns of the queries
->select('title', 'subtitle')
->from('pages')
->where(
// The union Expression Builder **must** be used on subqueries
$unionExpr->eq(
'pages.pid',
// Named parameters **must** be created on the outermost (union) query builder
$unionQueryBuilder->createNamedParameter($pageId, Connection::PARAM_INT),
),
);
return $queryBuilder;
}

private function getUnionPart2QueryBuilder(
Connection $connection,
QueryBuilder $unionQueryBuilder,
int $pageId,
): QueryBuilder {
$queryBuilder = $connection->createQueryBuilder();
// The union Expression Builder **must** be used on subqueries
$unionExpr = $unionQueryBuilder->expr();
$queryBuilder
// The column count of both subqueries must be the same
->select('header', 'subheader')
->from('tt_content')
->where(
$unionExpr->eq(
'tt_content.pid',
// Named parameters **must** be created on the outermost (union) query builder
$unionQueryBuilder->createNamedParameter($pageId, Connection::PARAM_INT),
),
);
return $queryBuilder;
}
}