NEW Add sql UNION abstraction

This commit is contained in:
Guy Sartorelli 2023-08-04 15:38:28 +12:00
parent fac3356739
commit 76da701b6b
No known key found for this signature in database
GPG Key ID: F313E3B9504D496A
4 changed files with 140 additions and 1 deletions

View File

@ -68,13 +68,23 @@ class DBQueryBuilder
*/
protected function buildSelectQuery(SQLSelect $query, array &$parameters)
{
$sql = $this->buildSelectFragment($query, $parameters);
$needsParenthisis = count($query->getUnions()) > 0;
$nl = $this->getSeparator();
$sql = '';
if ($needsParenthisis) {
$sql .= "({$nl}";
}
$sql .= $this->buildSelectFragment($query, $parameters);
$sql .= $this->buildFromFragment($query, $parameters);
$sql .= $this->buildWhereFragment($query, $parameters);
$sql .= $this->buildGroupByFragment($query, $parameters);
$sql .= $this->buildHavingFragment($query, $parameters);
$sql .= $this->buildOrderByFragment($query, $parameters);
$sql .= $this->buildLimitFragment($query, $parameters);
if ($needsParenthisis) {
$sql .= "{$nl})";
}
$sql .= $this->buildUnionFragment($query, $parameters);
return $sql;
}
@ -285,6 +295,37 @@ class DBQueryBuilder
return "{$nl}WHERE (" . implode("){$nl}{$connective} (", $where) . ")";
}
/**
* Return the UNION clause(s) ready for inserting into a query.
*/
protected function buildUnionFragment(SQLSelect $query, array &$parameters): string
{
$unions = $query->getUnions();
if (empty($unions)) {
return '';
}
$nl = $this->getSeparator();
$clauses = [];
foreach ($unions as $union) {
$unionQuery = $union['query'];
$unionType = $union['type'];
$clause = "{$nl}UNION";
if ($unionType) {
$clause .= " $unionType";
}
$clause .= "$nl($nl" . $this->buildSelectQuery($unionQuery, $parameters) . "$nl)";
$clauses[] = $clause;
}
return implode('', $clauses);
}
/**
* Returns the ORDER BY clauses ready for inserting into a query.
*

View File

@ -667,6 +667,20 @@ class DataQuery
return $this;
}
/**
* Add a query to UNION with.
*
* @param string|null $type One of the SQLSelect::UNION_ALL or SQLSelect::UNION_DISTINCT constants - or null for a default union
*/
public function union(DataQuery|SQLSelect $query, ?string $type = null): static
{
if ($query instanceof self) {
$query = $query->query();
}
$this->query->addUnion($query, $type);
return $this;
}
/**
* Create a disjunctive subgroup.
*

View File

@ -5,6 +5,7 @@ namespace SilverStripe\ORM\Queries;
use SilverStripe\Core\Injector\Injector;
use SilverStripe\ORM\DB;
use InvalidArgumentException;
use LogicException;
/**
* Object representing a SQL SELECT query.
@ -12,6 +13,9 @@ use InvalidArgumentException;
*/
class SQLSelect extends SQLConditionalExpression
{
public const UNION_ALL = 'ALL';
public const UNION_DISTINCT = 'DISTINCT';
/**
* An array of SELECT fields, keyed by an optional alias.
@ -36,6 +40,11 @@ class SQLSelect extends SQLConditionalExpression
*/
protected $having = [];
/**
* An array of subqueries to union with this one.
*/
protected array $union = [];
/**
* If this is true DISTINCT will be added to the SQL.
*
@ -532,6 +541,29 @@ class SQLSelect extends SQLConditionalExpression
return $conditions;
}
/**
* Add a select query to UNION with.
*
* @param string|null $type One of the UNION_ALL or UNION_DISTINCT constants - or null for a default union
*/
public function addUnion(self $query, ?string $type = null): static
{
if ($type && $type !== self::UNION_ALL && $type !== self::UNION_DISTINCT) {
throw new LogicException('Union $type must be one of the constants UNION_ALL or UNION_DISTINCT.');
}
$this->union[] = ['query' => $query, 'type' => $type];
return $this;
}
/**
* Get all of the queries that will be UNIONed with this one.
*/
public function getUnions(): array
{
return $this->union;
}
/**
* Return a list of GROUP BY clauses used internally.
*

View File

@ -3,12 +3,14 @@
namespace SilverStripe\ORM\Tests;
use InvalidArgumentException;
use LogicException;
use SilverStripe\ORM\DB;
use SilverStripe\ORM\Connect\MySQLDatabase;
use SilverStripe\ORM\Queries\SQLSelect;
use SilverStripe\SQLite\SQLite3Database;
use SilverStripe\PostgreSQL\PostgreSQLDatabase;
use SilverStripe\Dev\SapphireTest;
use SilverStripe\ORM\ArrayList;
class SQLSelectTest extends SapphireTest
{
@ -858,6 +860,56 @@ class SQLSelectTest extends SapphireTest
$query->execute();
}
public function provideUnion()
{
return [
// Note that a default (null) UNION is identical to a DISTINCT UNION
[
'unionQuery' => new SQLSelect([1, 2]),
'type' => null,
'expected' => [
[1 => 1, 2 => 2],
],
],
[
'unionQuery' => new SQLSelect([1, 2]),
'type' => SQLSelect::UNION_DISTINCT,
'expected' => [
[1 => 1, 2 => 2],
],
],
[
'unionQuery' => new SQLSelect([1, 2]),
'type' => SQLSelect::UNION_ALL,
'expected' => [
[1 => 1, 2 => 2],
[1 => 1, 2 => 2],
],
],
[
'unionQuery' => new SQLSelect([1, 2]),
'type' => 'tulips',
'expected' => LogicException::class,
],
];
}
/**
* @dataProvider provideUnion
*/
public function testUnion(SQLSelect $unionQuery, ?string $type, string|array $expected)
{
if (is_string($expected)) {
$this->expectException($expected);
$this->expectExceptionMessage('Union $type must be one of the constants UNION_ALL or UNION_DISTINCT.');
}
$query = new SQLSelect([1, 2]);
$query->addUnion($unionQuery, $type);
$this->assertSame($expected, iterator_to_array($query->execute(), true));
}
public function testBaseTableAliases()
{
$query = SQLSelect::create('*', ['"MyTableAlias"' => '"MyTable"']);