Skip to content

Commit 8937573

Browse files
sbuerkmaddy2101
authored andcommitted
[FEATURE] Add UNION Clause support to the QueryBuilder
The `UNION Clause` is used to combine the result-set of two or more `SELECT` SQL queries suported by all database vendors - at least on a shared basic level with the usual special vendor enhancements. There is a common shared subset working 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 Instead of introducing the `UNION Clause` support into the TYPO3 QueryBuilder, the challenge was taken to add this directly into Doctrine DBAL [1]. The effort was rewarded and with the release of `Doctrine DBAL 4.1.0` `UNION Clause` [2] the support is included. This change adopts the new feature into the extended `ConcreteQueryBuilder` and `QueryBuilder` to support extension authors with a simple and usable interface to build `UNION (DISTINCT)` and `UNION ALL` queries. [1] doctrine/dbal#6369 [2] https://github.com/doctrine/dbal/releases/tag/4.1.0 Resolves: #104631 Related: #104628 Releases: main Change-Id: I443b762fdc6a9f1ed77b3d655d0ab2f371a56d50 Reviewed-on: https://review.typo3.org/c/Packages/TYPO3.CMS/+/83943 Reviewed-by: Anja Leichsenring <[email protected]> Tested-by: core-ci <[email protected]> Tested-by: Christian Kuhn <[email protected]> Tested-by: Anja Leichsenring <[email protected]> Reviewed-by: Christian Kuhn <[email protected]>
1 parent 1c9f4da commit 8937573

File tree

7 files changed

+658
-0
lines changed

7 files changed

+658
-0
lines changed

typo3/sysext/core/Classes/Database/Query/ConcreteQueryBuilder.php

+47
Original file line numberDiff line numberDiff line change
@@ -29,6 +29,8 @@
2929
use Doctrine\DBAL\Query\QueryBuilder as DoctrineQueryBuilder;
3030
use Doctrine\DBAL\Query\QueryException;
3131
use Doctrine\DBAL\Query\QueryType;
32+
use Doctrine\DBAL\Query\Union;
33+
use Doctrine\DBAL\Query\UnionType;
3234
use TYPO3\CMS\Core\Database\Connection;
3335

3436
/**
@@ -113,6 +115,13 @@ class ConcreteQueryBuilder extends DoctrineQueryBuilder
113115
*/
114116
protected WithCollection $typo3_with;
115117

118+
/**
119+
* The QueryBuilder for the union parts.
120+
*
121+
* @var Union[]
122+
*/
123+
protected array $typo3_unionParts = [];
124+
116125
/**
117126
* Initializes a new <tt>QueryBuilder</tt>.
118127
*
@@ -146,6 +155,44 @@ public function __clone()
146155
}
147156
}
148157

158+
/**
159+
* Specifies union parts to be used to build a UNION query.
160+
* Replaces any previously specified parts.
161+
*
162+
* <code>
163+
* $qb = $conn->createQueryBuilder()
164+
* ->union('SELECT 1 AS field1', 'SELECT 2 AS field1');
165+
* </code>
166+
*
167+
* @return $this
168+
*/
169+
public function union(string|ConcreteQueryBuilder|DoctrineQueryBuilder $part): self
170+
{
171+
parent::union($part);
172+
$this->type = QueryType::UNION;
173+
$this->typo3_unionParts = [new Union($part)];
174+
return $this;
175+
}
176+
177+
/**
178+
* Add parts to be used to build a UNION query.
179+
*
180+
* <code>
181+
* $qb = $conn->createQueryBuilder()
182+
* ->union('SELECT 1 AS field1')
183+
* ->addUnion('SELECT 2 AS field1', 'SELECT 3 AS field1')
184+
* </code>
185+
*
186+
* @return $this
187+
*/
188+
public function addUnion(string|ConcreteQueryBuilder|DoctrineQueryBuilder $part, UnionType $type = UnionType::DISTINCT): self
189+
{
190+
parent::addUnion($part, $type);
191+
$this->type = QueryType::UNION;
192+
$this->typo3_unionParts[] = new Union($part, $type);
193+
return $this;
194+
}
195+
149196
/**
150197
* Specifies an item that is to be returned in the query result.
151198
* Replaces any previously specified selections, if any.

typo3/sysext/core/Classes/Database/Query/QueryBuilder.php

+39
Original file line numberDiff line numberDiff line change
@@ -29,6 +29,7 @@
2929
use Doctrine\DBAL\Query\Join;
3030
use Doctrine\DBAL\Query\QueryBuilder as DoctrineQueryBuilder;
3131
use Doctrine\DBAL\Query\QueryType;
32+
use Doctrine\DBAL\Query\UnionType;
3233
use Doctrine\DBAL\Result;
3334
use Doctrine\DBAL\Statement;
3435
use Doctrine\DBAL\Types\StringType;
@@ -455,6 +456,44 @@ protected function getCountExpression(string $column): string
455456
return 'COUNT(' . $column . ')';
456457
}
457458

459+
/**
460+
* Specifies union parts to be used to build a UNION query.
461+
* Replaces any previously specified parts.
462+
*
463+
* ```php
464+
* $qb = $conn->createQueryBuilder()
465+
* ->union('SELECT 1 AS field1', 'SELECT 2 AS field1');
466+
* ```
467+
*
468+
* @return $this
469+
*/
470+
public function union(string|QueryBuilder|ConcreteQueryBuilder|DoctrineQueryBuilder $part): QueryBuilder
471+
{
472+
$this->type = QueryType::UNION;
473+
$concreteQueryBuilder = $this->getConcreteQueryBuilder();
474+
$concreteQueryBuilder->union($part);
475+
return $this;
476+
}
477+
478+
/**
479+
* Add parts to be used to build a UNION query.
480+
*
481+
* ```php
482+
* $qb = $conn->createQueryBuilder()
483+
* ->union('SELECT 1 AS field1')
484+
* ->addUnion('SELECT 2 AS field1', 'SELECT 3 AS field1')
485+
* ```
486+
*
487+
* @return $this
488+
*/
489+
public function addUnion(string|QueryBuilder|ConcreteQueryBuilder|DoctrineQueryBuilder $part, UnionType $type = UnionType::DISTINCT): QueryBuilder
490+
{
491+
$this->type = QueryType::UNION;
492+
$concreteQueryBuilder = $this->getConcreteQueryBuilder();
493+
$concreteQueryBuilder->addUnion($part, $type);
494+
return $this;
495+
}
496+
458497
/**
459498
* Specifies items that are to be returned in the query result.
460499
* Replaces any previously specified selections, if any.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,156 @@
1+
.. include:: /Includes.rst.txt
2+
3+
.. _feature-104631-1723714985:
4+
5+
=================================================================
6+
Feature: #104631 - Add `UNION Clause` support to the QueryBuilder
7+
=================================================================
8+
9+
See :issue:`104631`
10+
11+
Description
12+
===========
13+
14+
The :sql:`UNION` clause is used to combine the result-set of two or more
15+
:sql:`SELECT` statements, which all database vendors supports with usual
16+
specialities for each.
17+
18+
Still, there is a common shared subset which works for all of them:
19+
20+
.. code-block:: sql
21+
22+
SELECT column_name(s) FROM table1
23+
WHERE ...
24+
25+
UNION <ALL | DISTINCT>
26+
27+
SELECT column_name(s) FROM table2
28+
WHERE ...
29+
30+
ORDER BY ...
31+
LIMIT x OFFSET y
32+
33+
with shared requirements:
34+
35+
* Each SELECT must return the same fields in number, naming and order.
36+
* Each SELECT must not have ORDER BY, expect MySQL allowing it to be used as sub
37+
query expression encapsulated in parenthesis.
38+
39+
Generic :sql:`UNION` clause support has been contributed to `Doctrine DBAL` and
40+
is included since `Release 4.1.0 <https://github.com/doctrine/dbal/releases/tag/4.1.0>`__
41+
which introduces two new API method on the QueryBuilder:
42+
43+
* :php:`union(string|QueryBuilder $part)` to create first UNION query part
44+
* :php:`addUnion(string|QueryBuilder $part, UnionType $type = UnionType::DISTINCT)`
45+
to add addtional :sql:`UNION (ALL|DISTINCT)` query parts with the selected union
46+
query type.
47+
48+
TYPO3 decorates the Doctrine DBAL QueryBuilder to provide for most API methods automatic
49+
quoting of identifiers and values **and** to appliy database restrictions automatically
50+
for :sql:`SELECT` queries.
51+
52+
The Doctrine DBAL API has been adopted now to provide the same surface for the
53+
TYPO3 :php:`\TYPO3\CMS\Core\Database\Query\QueryBuilder` and the intermediate
54+
:php:`\TYPO3\CMS\Core\Database\Query\ConcreteQueryBuilder` to make it easier to
55+
create :sql:`UNION` clause queries. The API on both methods allows to provide
56+
dedicated QueryBuilder instances or direct queries as strings in case it is needed.
57+
58+
.. note::
59+
60+
Providing :sql:`UNION` parts as plain string requires the developer to take
61+
care of proper quoting and escaping within the query part.
62+
63+
Another point worth to mention is, that only `named placeholder` can be used
64+
and registered on the most outer :php:`QueryBuilder` object instance, similar
65+
to advanced query creation using for example :sql:`SUB QUERIES`.
66+
67+
.. warning::
68+
69+
:php:`QueryBuilder` can be used create :sql:`UNION` clause queries not
70+
compatible with all database, for example using LIMIT/OFFSET in each
71+
part query or other stuff.
72+
73+
UnionType::DISTINCT and UnionType::ALL
74+
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
75+
76+
Each subsequent part needs to be defined either as :sql:`UNION DISTINCT` or
77+
:sql:`UNION ALL` which could have not so obvious effects.
78+
79+
For example, using :sql:`UNION ALL` for all parts in between except for the last
80+
one would generate larger result sets first, but discards duplicates when adding
81+
the last result set. On the other side, using :sql:`UNION ALL` tells the query
82+
optimizer **not** to scan for duplicats and remove them at all which can be a
83+
performance improvement - if you can deal with duplicates it can be ensured that
84+
each part does not produce same outputs.
85+
86+
Example: Compose a :sql:`UNION` clause query
87+
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
88+
89+
.. code-block:: php
90+
:caption: Custom service class using an UNION query to retrieve data.
91+
92+
use TYPO3\CMS\Core\Database\Connection;
93+
use TYPO3\CMS\Core\Database\ConnectionPool;
94+
use TYPO3\CMS\Core\Database\Query\QueryBuilder;
95+
96+
final readonly MyService {
97+
public function __construct(
98+
private ConnectionPool $connectionPool,
99+
) {}
100+
101+
public function executeUnionQuery(
102+
int $pageIdOne,
103+
int $pageIdTwo,
104+
): ?array {
105+
$connection = $this->connectionPool->getConnectionForTable('pages');
106+
$unionQueryBuilder = $connection->createQueryBuilder();
107+
$firstPartQueryBuilder = $connection->createQueryBuilder();
108+
$firstPartQueryBuilder->getRestrictions()->removeAll();
109+
$secondPartQueryBuilder = $connection->createQueryBuilder();
110+
$secondPartQueryBuilder->getRestrictions()->removeAll();
111+
$expr = $unionQueryBuilder->expr();
112+
113+
$firstPartQueryBuilder
114+
->select('uid', 'pid', 'title')
115+
->from('pages')
116+
->where(
117+
$expr->eq(
118+
'pages.uid',
119+
$unionQueryBuilder->createNamedParameter($pageIdOne),
120+
);
121+
$secondPartQueryBuilder
122+
->select('uid', 'pid', 'title')
123+
->from('pages')
124+
->where(
125+
$expr->eq(
126+
'pages.uid',
127+
$unionQueryBuilder->createNamedParameter($pageIdOne),
128+
);
129+
130+
return $unionQueryBuilder
131+
->union($firstPartQueryBuilder)
132+
->addUnion($secondPartQueryBuilder, UnionType::DISTINCT)
133+
->orderBy('uid', 'ASC')
134+
->executeQuery()
135+
->fetchAllAssociative();
136+
}
137+
}
138+
139+
which would create following query for MySQL with :php:`$pageIdOne = 100` and
140+
:php:`$pageIdTwo = 10`:
141+
142+
.. code-block:: sql
143+
144+
(SELECT `uid`, `pid`, `title` FROM pages WHERE `pages`.`uid` = 100)
145+
UNION
146+
(SELECT `uid`, `pid`, `title` FROM pages WHERE `pages`.`uid` = 10)
147+
ORDER BY `uid` ASC
148+
149+
150+
Impact
151+
======
152+
153+
Extension authors can use the new :php:`QueryBuilder` methods to build more
154+
advanced queries.
155+
156+
.. index:: Database, PHP-API, ext:core
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
"pages",
2+
,"uid","pid","doktype","hidden","title",
3+
,1,0,1,0,"page 1",
4+
,2,0,254,0,"sysfolder 2",
5+
,3,0,1,0,"page 3",
6+
,4,0,254,0,"sysfolder 4",

0 commit comments

Comments
 (0)