NEW Add ORM abstraction for "WITH" clauses (#10943)

This commit is contained in:
Guy Sartorelli 2023-10-02 15:25:14 +13:00 committed by GitHub
parent 11c0198b9d
commit 44b170098e
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
14 changed files with 1051 additions and 7 deletions

View File

@ -3,6 +3,7 @@
namespace SilverStripe\ORM\Connect;
use InvalidArgumentException;
use SilverStripe\Core\Convert;
use SilverStripe\ORM\Queries\SQLExpression;
use SilverStripe\ORM\Queries\SQLSelect;
use SilverStripe\ORM\Queries\SQLDelete;
@ -74,6 +75,7 @@ class DBQueryBuilder
if ($needsParenthisis) {
$sql .= "({$nl}";
}
$sql .= $this->buildWithFragment($query, $parameters);
$sql .= $this->buildSelectFragment($query, $parameters);
$sql .= $this->buildFromFragment($query, $parameters);
$sql .= $this->buildWhereFragment($query, $parameters);
@ -165,6 +167,41 @@ class DBQueryBuilder
return $sql;
}
/**
* Returns the WITH clauses ready for inserting into a query.
*/
protected function buildWithFragment(SQLSelect $query, array &$parameters): string
{
$with = $query->getWith();
if (empty($with)) {
return '';
}
$nl = $this->getSeparator();
$clauses = [];
foreach ($with as $name => $bits) {
$clause = $bits['recursive'] ? 'RECURSIVE ' : '';
$clause .= Convert::symbol2sql($name);
if (!empty($bits['cte_fields'])) {
$cteFields = $bits['cte_fields'];
// Ensure all cte fields are escaped correctly
array_walk($cteFields, function (&$colName) {
$colName = preg_match('/^".*"$/', $colName) ? $colName : Convert::symbol2sql($colName);
});
$clause .= ' (' . implode(', ', $cteFields) . ')';
}
$clause .= " AS ({$nl}";
$clause .= $this->buildSelectQuery($bits['query'], $parameters);
$clause .= "{$nl})";
$clauses[] = $clause;
}
return 'WITH ' . implode(",{$nl}", $clauses) . $nl;
}
/**
* Returns the SELECT clauses ready for inserting into a query.
*

View File

@ -636,6 +636,17 @@ abstract class Database
$invertedMatch = false
);
/**
* Determines if this database supports Common Table Expression (aka WITH) clauses.
* By default it is assumed that it doesn't unless this method is explicitly overridden.
*
* @param bool $recursive if true, checks specifically if recursive CTEs are supported.
*/
public function supportsCteQueries(bool $recursive = false): bool
{
return false;
}
/**
* Determines if this database supports transactions
*
@ -654,7 +665,6 @@ abstract class Database
return false;
}
/**
* Determines if the used database supports given transactionMode as an argument to startTransaction()
* If transactions are completely unsupported, returns false.

View File

@ -313,6 +313,41 @@ class MySQLDatabase extends Database implements TransactionManager
return $list;
}
public function supportsCteQueries(bool $recursive = false): bool
{
$version = $this->getVersion();
$mariaDBVersion = $this->getMariaDBVersion($version);
if ($mariaDBVersion) {
// MariaDB has supported CTEs since 10.2.1, and recursive CTEs from 10.2.2
// see https://mariadb.com/kb/en/mariadb-1021-release-notes/ and https://mariadb.com/kb/en/mariadb-1022-release-notes/
$supportedFrom = $recursive ? '10.2.2' : '10.2.1';
return $this->compareVersion($mariaDBVersion, $supportedFrom) >= 0;
}
// MySQL has supported both kinds of CTEs since 8.0.1
// see https://dev.mysql.com/doc/relnotes/mysql/8.0/en/news-8-0-1.html
return $this->compareVersion($version, '8.0.1') >= 0;
}
private function getMariaDBVersion(string $version): ?string
{
// MariaDB versions look like "5.5.5-10.6.8-mariadb-1:10.6.8+maria~focal"
// or "10.8.3-MariaDB-1:10.8.3+maria~jammy"
// The relevant part is the x.y.z-mariadb portion.
if (!preg_match('/((\d+\.){2}\d+)-mariadb/i', $version, $matches)) {
return null;
}
return $matches[1];
}
private function compareVersion(string $actualVersion, string $atLeastVersion): int
{
// Assume it's lower if it's not a proper version number
if (!preg_match('/^(\d+\.){2}\d+$/', $actualVersion)) {
return -1;
}
return version_compare($actualVersion, $atLeastVersion);
}
/**
* Returns the TransactionManager to handle transactions for this database.
*

View File

@ -678,7 +678,7 @@ class DataQuery
*/
public function union(DataQuery|SQLSelect $query, ?string $type = null): static
{
if ($query instanceof self) {
if ($query instanceof DataQuery) {
$query = $query->query();
}
$this->query->addUnion($query, $type);
@ -705,8 +705,6 @@ class DataQuery
return new DataQuery_SubGroup($this, 'OR', $clause);
}
/**
* Create a conjunctive subgroup
*
@ -727,6 +725,39 @@ class DataQuery
return new DataQuery_SubGroup($this, 'AND', $clause);
}
/**
* Adds a Common Table Expression (CTE), aka WITH clause.
*
* Use of this method should usually be within a conditional check against DB::get_conn()->supportsCteQueries().
*
* @param string $name The name of the WITH clause, which can be referenced in any queries UNIONed to the $query
* and in this query directly, as though it were a table name.
* @param string[] $cteFields Aliases for any columns selected in $query which can be referenced in any queries
* UNIONed to the $query and in this query directly, as though they were columns in a real table.
* NOTE: If $query is a DataQuery, then cteFields must be the names of real columns on that DataQuery's data class.
*/
public function with(string $name, DataQuery|SQLSelect $query, array $cteFields = [], bool $recursive = false): static
{
$schema = DataObject::getSchema();
// If the query is a DataQuery, make sure all manipulators, joins, etc are applied
if ($query instanceof self) {
$cteDataClass = $query->dataClass();
$query = $query->query();
// DataQuery wants to select ALL columns by default,
// but if we're setting cteFields then we only want to select those fields.
if (!empty($cteFields)) {
$selectFields = array_map(fn($colName) => $schema->sqlColumnForField($cteDataClass, $colName), $cteFields);
$query->setSelect($selectFields);
}
}
// Add the WITH clause
$this->query->addWith($name, $query, $cteFields, $recursive);
return $this;
}
/**
* Adds a WHERE clause.
*

View File

@ -45,6 +45,18 @@ class SQLSelect extends SQLConditionalExpression
*/
protected array $union = [];
/**
* An array of WITH clauses.
* This array is indexed with the name for the temporary table generated for the WITH clause,
* and contains data in the following format:
* [
* 'cte_fields' => string[],
* 'query' => SQLSelect|null,
* 'recursive' => boolean,
* ]
*/
protected array $with = [];
/**
* If this is true DISTINCT will be added to the SQL.
*
@ -546,7 +558,7 @@ class SQLSelect extends SQLConditionalExpression
*
* @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
public function addUnion(SQLSelect $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.');
@ -564,6 +576,37 @@ class SQLSelect extends SQLConditionalExpression
return $this->union;
}
/**
* Adds a Common Table Expression (CTE), aka WITH clause.
*
* Use of this method should usually be within a conditional check against DB::get_conn()->supportsCteQueries().
*
* @param string $name The name of the WITH clause, which can be referenced in any queries UNIONed to the $query
* and in this query directly, as though it were a table name.
* @param string[] $cteFields Aliases for any columns selected in $query which can be referenced in any queries
* UNIONed to the $query and in this query directly, as though they were columns in a real table.
*/
public function addWith(string $name, SQLSelect $query, array $cteFields = [], bool $recursive = false): static
{
if (array_key_exists($name, $this->with)) {
throw new LogicException("WITH clause with name '$name' already exists.");
}
$this->with[$name] = [
'cte_fields' => $cteFields,
'query' => $query,
'recursive' => $recursive,
];
return $this;
}
/**
* Get the data which will be used to generate the WITH clause of the query
*/
public function getWith(): array
{
return $this->with;
}
/**
* Return a list of GROUP BY clauses used internally.
*

View File

@ -6,16 +6,18 @@ use SilverStripe\ORM\DataQuery;
use SilverStripe\ORM\DataObject;
use SilverStripe\ORM\DB;
use SilverStripe\Dev\SapphireTest;
use SilverStripe\ORM\ArrayList;
use SilverStripe\ORM\Queries\SQLSelect;
use SilverStripe\ORM\Tests\DataQueryTest\ObjectE;
use SilverStripe\Security\Member;
class DataQueryTest extends SapphireTest
{
protected static $fixture_file = 'DataQueryTest.yml';
protected static $extra_dataobjects = [
DataQueryTest\DataObjectAddsToQuery::class,
DataQueryTest\DateAndPriceObject::class,
DataQueryTest\ObjectA::class,
DataQueryTest\ObjectB::class,
DataQueryTest\ObjectC::class,
@ -25,6 +27,7 @@ class DataQueryTest extends SapphireTest
DataQueryTest\ObjectG::class,
DataQueryTest\ObjectH::class,
DataQueryTest\ObjectI::class,
SQLSelectTest\CteRecursiveObject::class,
SQLSelectTest\TestObject::class,
SQLSelectTest\TestBase::class,
SQLSelectTest\TestChild::class,
@ -574,4 +577,280 @@ class DataQueryTest extends SapphireTest
'exist is false when a limit returns no results'
);
}
public function provideWith()
{
return [
// Simple scenarios to test auto-join functionality
'naive CTE query with array join' => [
'dataClass' => DataQueryTest\DateAndPriceObject::class,
'name' => 'cte',
'query' => new SQLSelect(
['"DataQueryTest_DateAndPriceObject"."ID"'],
'"DataQueryTest_DateAndPriceObject"',
['"DataQueryTest_DateAndPriceObject"."Price" > 200']
),
'cteFields' => ['cte_id'],
'recursive' => false,
'extraManipulations' => [
'innerJoin' => ['cte', '"DataQueryTest_DateAndPriceObject"."ID" = "cte"."cte_id"'],
],
'expectedItems' => [
'fixtures' => [
'obj4',
'obj5',
],
],
],
'naive CTE query with string join' => [
'dataClass' => DataQueryTest\DateAndPriceObject::class,
'name' => 'cte',
'query' => new SQLSelect('200'),
'cteFields' => ['value'],
'recursive' => false,
'extraManipulations' => [
'innerJoin' => ['cte', '"DataQueryTest_DateAndPriceObject"."Price" < "cte"."value"'],
],
'expectedItems' => [
'fixtures' => [
'nullobj',
'obj1',
'obj2',
]
],
],
// Simple scenario to test where the query is another DataQuery
'naive CTE query with DataQuery' => [
'dataClass' => DataQueryTest\DateAndPriceObject::class,
'name' => 'cte',
'query' => DataQueryTest\ObjectF::class,
'cteFields' => ['MyDate'],
'recursive' => false,
'extraManipulations' => [
'innerJoin' => ['cte', '"DataQueryTest_DateAndPriceObject"."Date" = "cte"."MyDate"'],
],
'expectedItems' => [
'fixtures' => [
'obj1',
'obj2',
]
],
],
// Extrapolate missing data with a recursive query
// Missing data will be returned as records with no ID
'recursive CTE with extrapolated data' => [
'dataClass' => DataQueryTest\DateAndPriceObject::class,
'name' => 'dates',
'query' => (new SQLSelect(
'MIN("DataQueryTest_DateAndPriceObject"."Date")',
"DataQueryTest_DateAndPriceObject",
'"DataQueryTest_DateAndPriceObject"."Date" IS NOT NULL'
))->addUnion(
new SQLSelect(
'Date + INTERVAL 1 DAY',
'dates',
['Date + INTERVAL 1 DAY <= (SELECT MAX("DataQueryTest_DateAndPriceObject"."Date") FROM "DataQueryTest_DateAndPriceObject")']
),
SQLSelect::UNION_ALL
),
'cteFields' => ['Date'],
'recursive' => true,
'extraManipulations' => [
'selectField' => ['COALESCE("DataQueryTest_DateAndPriceObject"."Date", "dates"."Date")', 'Date'],
'setAllowCollidingFieldStatements' => [true],
'sort' => ['dates.Date'],
'rightJoin' => ['dates', '"DataQueryTest_DateAndPriceObject"."Date" = "dates"."Date"'],
],
'expectedItems' => [
'data' => [
['fixtureName' => 'obj5'],
['fixtureName' => 'obj4'],
['Date' => '2023-01-06'],
['Date' => '2023-01-05'],
['fixtureName' => 'obj3'],
['Date' => '2023-01-03'],
['fixtureName' => 'obj2'],
['fixtureName' => 'obj1'],
]
],
],
// Get the ancestors of a given record with a recursive query
'complex hierarchical CTE with explicit columns' => [
'dataClass' => SQLSelectTest\CteRecursiveObject::class,
'name' => 'hierarchy',
'query' => (
new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
"SQLSelectTestCteRecursive",
[['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."Title" = ?' => 'child of child1']]
)
)->addUnion(new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
['"hierarchy"', '"SQLSelectTestCteRecursive"'],
['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"']
)),
'cteFields' => ['parent_id'],
'recursive' => true,
'extraManipulations' => [
'innerJoin' => ['hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"'],
],
'expected' => [
'fixtures' => [
'grandparent',
'parent',
'child1',
],
],
],
];
}
/**
* @dataProvider provideWith
*/
public function testWith(
string $dataClass,
string $name,
string|SQLSelect $query,
array $cteFields,
bool $recursive,
array $extraManipulations,
array $expectedItems
) {
if (!DB::get_conn()->supportsCteQueries()) {
$this->markTestSkipped('The current database does not support WITH clauses');
}
if ($recursive && !DB::get_conn()->supportsCteQueries(true)) {
$this->markTestSkipped('The current database does not support recursive WITH clauses');
}
// We can't instantiate a DataQuery in a provider method because it requires the injector, which isn't
// initialised that early. So we just pass the dataclass instead and instiate the query here.
if (is_string($query)) {
$query = new DataQuery($query);
}
$dataQuery = new DataQuery($dataClass);
$dataQuery->with($name, $query, $cteFields, $recursive);
foreach ($extraManipulations as $method => $args) {
$dataQuery->$method(...$args);
}
$expected = [];
if (isset($expectedItems['fixtures'])) {
foreach ($expectedItems['fixtures'] as $fixtureName) {
$expected[] = $this->idFromFixture($dataClass, $fixtureName);
}
$this->assertEquals($expected, $dataQuery->execute()->column('ID'));
}
if (isset($expectedItems['data'])) {
foreach ($expectedItems['data'] as $data) {
if (isset($data['fixtureName'])) {
$data = $this->objFromFixture($dataClass, $data['fixtureName'])->toMap();
} else {
$data['ClassName'] = null;
$data['LastEdited'] = null;
$data['Created'] = null;
$data['Price'] = null;
$data['ID'] = null;
}
$expected[] = $data;
}
$this->assertListEquals($expected, new ArrayList(iterator_to_array($dataQuery->execute(), true)));
}
}
/**
* tests the WITH clause, using a DataQuery as the CTE query
*/
public function testWithUsingDataQuery()
{
if (!DB::get_conn()->supportsCteQueries(true)) {
$this->markTestSkipped('The current database does not support recursive WITH clauses');
}
$dataQuery = new DataQuery(SQLSelectTest\CteRecursiveObject::class);
$cteQuery = new DataQuery(SQLSelectTest\CteRecursiveObject::class);
$cteQuery->where([
'"SQLSelectTestCteRecursive"."ParentID" > 0',
'"SQLSelectTestCteRecursive"."Title" = ?' => 'child of child2'
]);
$cteQuery->union(new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
['"hierarchy"', '"SQLSelectTestCteRecursive"'],
[
'"SQLSelectTestCteRecursive"."ParentID" > 0',
'"SQLSelectTestCteRecursive"."ID" = "hierarchy"."ParentID"'
]
));
$dataQuery->with('hierarchy', $cteQuery, ['ParentID'], true);
$dataQuery->innerJoin('hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."ParentID"');
$expectedFixtures = [
'child2',
'parent',
'grandparent',
];
$expectedData = [];
foreach ($expectedFixtures as $fixtureName) {
$expectedData[] = $this->objFromFixture(SQLSelectTest\CteRecursiveObject::class, $fixtureName)->toMap();
}
$this->assertListEquals($expectedData, new ArrayList(iterator_to_array($dataQuery->execute(), true)));
}
/**
* tests the WITH clause, using a DataQuery as the CTE query and as the unioned recursive query
*/
public function testWithUsingOnlyDataQueries()
{
if (!DB::get_conn()->supportsCteQueries(true)) {
$this->markTestSkipped('The current database does not support recursive WITH clauses');
}
$dataQuery = new DataQuery(SQLSelectTest\CteRecursiveObject::class);
$cteQuery = new DataQuery(SQLSelectTest\CteRecursiveObject::class);
$cteQuery->where([
'"SQLSelectTestCteRecursive"."ParentID" > 0',
'"SQLSelectTestCteRecursive"."Title" = ?' => 'child of child2'
]);
$cteQuery->union((new DataQuery(SQLSelectTest\CteRecursiveObject::class))
->innerJoin('hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."ParentID"')
->where('"SQLSelectTestCteRecursive"."ParentID" > 0')
->sort(null)
->distinct(false));
// This test exists because previously when $cteFields was empty, it would cause an error with the above setup.
$dataQuery->with('hierarchy', $cteQuery, [], true);
$dataQuery->innerJoin('hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."ParentID"');
$expectedFixtures = [
'child2',
'parent',
'grandparent',
];
$expectedData = [];
foreach ($expectedFixtures as $fixtureName) {
$expectedData[] = $this->objFromFixture(SQLSelectTest\CteRecursiveObject::class, $fixtureName)->toMap();
}
$this->assertListEquals($expectedData, new ArrayList(iterator_to_array($dataQuery->execute(), true)));
}
/**
* Tests that CTE queries have appropriate JOINs for subclass tables etc.
* If `$query->query()->` was replaced with `$query->query->` in DataQuery::with(), this test would throw an exception.
* @doesNotPerformAssertions
*/
public function testWithUsingDataQueryAppliesRelations()
{
if (!DB::get_conn()->supportsCteQueries()) {
$this->markTestSkipped('The current database does not support WITH clauses');
}
$dataQuery = new DataQuery(DataQueryTest\ObjectG::class);
$cteQuery = new DataQuery(DataQueryTest\ObjectG::class);
$cteQuery->where(['"DataQueryTest_G"."SubClassOnlyField" = ?' => 'This is the one']);
$dataQuery->with('test_implicit_joins', $cteQuery, ['ID']);
$dataQuery->innerJoin('test_implicit_joins', '"DataQueryTest_G"."ID" = "test_implicit_joins"."ID"');
// This will throw an exception if it fails - it passes if there's no exception.
$dataQuery->execute();
}
}

View File

@ -9,6 +9,16 @@ SilverStripe\ORM\Tests\DataQueryTest\ObjectE:
Title: 'Second'
SortOrder: 2
SilverStripe\ORM\Tests\DataQueryTest\ObjectF:
query1:
MyDate: '2023-06-01'
query2:
MyDate: '2023-01-01'
query3:
MyDate: '2023-01-02'
query4:
MyDate: '2023-06-02'
SilverStripe\ORM\Tests\DataQueryTest\ObjectI:
query1:
Title: 'First'
@ -41,3 +51,42 @@ SilverStripe\ORM\Tests\DataQueryTest\DataObjectAddsToQuery:
obj1:
FieldOne: 'This is a value'
FieldTwo: 'This is also a value'
SilverStripe\ORM\Tests\DataQueryTest\DateAndPriceObject:
nullobj:
Date: null
Price: null
obj1:
Price: 0
Date: '2023-01-01'
obj2:
Price: 100
Date: '2023-01-02'
obj3:
Price: 200
Date: '2023-01-04'
obj4:
Price: 300
Date: '2023-01-07'
obj5:
Price: 400
Date: '2023-01-08'
SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject:
grandparent:
Title: 'grandparent'
parent:
Title: 'parent'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.grandparent
child1:
Title: 'child1'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.parent
child2:
Title: 'child2'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.parent
child-of-child1:
Title: 'child of child1'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.child1
child-of-child2:
Title: 'child of child2'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.child2

View File

@ -0,0 +1,16 @@
<?php
namespace SilverStripe\ORM\Tests\DataQueryTest;
use SilverStripe\Dev\TestOnly;
use SilverStripe\ORM\DataObject;
class DateAndPriceObject extends DataObject implements TestOnly
{
private static $table_name = 'DataQueryTest_DateAndPriceObject';
private static $db = [
'Date' => 'Date',
'Price' => 'Int',
];
}

View File

@ -8,6 +8,10 @@ class ObjectG extends ObjectC implements TestOnly
{
private static $table_name = 'DataQueryTest_G';
private static $db = [
'SubClassOnlyField' => 'Text',
];
private static $belongs_many_many = [
'ManyTestEs' => ObjectE::class,
];

View File

@ -8,6 +8,8 @@ use SilverStripe\ORM\DB;
use SilverStripe\ORM\Connect\MySQLiConnector;
use SilverStripe\ORM\Queries\SQLUpdate;
use SilverStripe\Dev\SapphireTest;
use SilverStripe\ORM\Connect\MySQLDatabase;
use SilverStripe\ORM\Tests\MySQLSchemaManagerTest\MySQLDBDummy;
class MySQLDatabaseTest extends SapphireTest
{
@ -110,4 +112,105 @@ class MySQLDatabaseTest extends SapphireTest
$this->assertInstanceOf(MySQLQuery::class, $result);
$this->assertEquals(1, DB::affected_rows());
}
public function provideSupportsCte()
{
return [
// mysql unsupported
[
'version' => '1.1.1',
'expected' => false,
'expectedRecursive' => false,
],
[
'version' => '5.9999.9999',
'expected' => false,
'expectedRecursive' => false,
],
[
'version' => '8.0.0',
'expected' => false,
'expectedRecursive' => false,
],
// mysql supported
[
'version' => '8.0.1',
'expected' => true,
'expectedRecursive' => true,
],
[
'version' => '10.2.0',
'expected' => true,
'expectedRecursive' => true,
],
[
'version' => '999.999.999',
'expected' => true,
'expectedRecursive' => true,
],
// mariaDB unsupported (various formats)
[
'version' => '5.5.5-10.2.0-mariadb-1:10.6.8+maria~focal',
'expected' => false,
'expectedRecursive' => false,
],
[
'version' => '10.2.0-mariadb-1:10.6.8+maria~jammy',
'expected' => false,
'expectedRecursive' => false,
],
[
'version' => '10.2.0-mariadb-1:10.2.0+maria~focal',
'expected' => false,
'expectedRecursive' => false,
],
// mariadb supported (various formats)
[
'version' => '5.5.5-10.2.1-mariadb-1:10.6.8+maria~focal',
'expected' => true,
'expectedRecursive' => false,
],
[
'version' => '10.2.1-mariadb-1:10.6.8+maria~jammy',
'expected' => true,
'expectedRecursive' => false,
],
[
'version' => '10.2.1-mariadb-1:10.2.1+maria~focal',
'expected' => true,
'expectedRecursive' => false,
],
[
'version' => '10.2.2-mariadb-1:10.2.2+maria~jammy',
'expected' => true,
'expectedRecursive' => true,
],
[
'version' => '5.5.5-10.2.2-mariadb-1:10.2.2+maria~jammy',
'expected' => true,
'expectedRecursive' => true,
],
[
'version' => '5.5.5-999.999.999-mariadb-1:10.2.2+maria~jammy',
'expected' => true,
'expectedRecursive' => true,
],
// completely invalid versions
[
'version' => '999.999.999-some-random-string',
'expected' => false,
'expectedRecursive' => false,
],
];
}
/**
* @dataProvider provideSupportsCte
*/
public function testSupportsCte(string $version, bool $expected, bool $expectedRecursive)
{
$database = new MySQLDBDummy($version);
$this->assertSame($expected, $database->supportsCteQueries());
$this->assertSame($expectedRecursive, $database->supportsCteQueries(true));
}
}

View File

@ -11,6 +11,9 @@ use SilverStripe\SQLite\SQLite3Database;
use SilverStripe\PostgreSQL\PostgreSQLDatabase;
use SilverStripe\Dev\SapphireTest;
use SilverStripe\ORM\ArrayList;
use SilverStripe\ORM\Connect\DatabaseException;
use SilverStripe\ORM\Tests\SQLSelectTest\CteDatesObject;
use SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject;
class SQLSelectTest extends SapphireTest
{
@ -20,7 +23,9 @@ class SQLSelectTest extends SapphireTest
protected static $extra_dataobjects = [
SQLSelectTest\TestObject::class,
SQLSelectTest\TestBase::class,
SQLSelectTest\TestChild::class
SQLSelectTest\TestChild::class,
SQLSelectTest\CteDatesObject::class,
SQLSelectTest\CteRecursiveObject::class,
];
protected $oldDeprecation = null;
@ -948,4 +953,364 @@ class SQLSelectTest extends SapphireTest
$sql
);
}
public function provideWith()
{
// Each of these examples shows it working with aliased implicit columns, and with explicit CTE columns.
// Most of these examples are derived from https://dev.mysql.com/doc/refman/8.0/en/with.html
return [
// Just a CTE, no union
'basic CTE with aliased columns' => [
'name' => 'cte',
'query' => new SQLSelect(['col1' => 1, 'col2' => 2]),
'cteFields' => [],
'recursive' => false,
'selectFields' => ['col1', 'col2'],
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [['col1' => 1, 'col2' => 2]],
],
'basic CTE with explicit columns' => [
'name' => 'cte',
'query' => new SQLSelect([1, 2]),
'cteFields' => ['col1', 'col2'],
'recursive' => false,
'selectFields' => ['col1', 'col2'],
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [['col1' => 1, 'col2' => 2]],
],
// CTE with a simple union, non-recursive
'basic unioned CTE with aliased columns' => [
'name' => 'cte',
'query' => (new SQLSelect(['col1' => 1, 'col2' => 2]))->addUnion(
new SQLSelect(['ignoredAlias1' => '3', 'ignoredAlias2' => '4']),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => false,
'selectFields' => ['col1', 'col2'],
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [
['col1' => 1, 'col2' => 2],
['col1' => 3, 'col2' => 4],
],
],
'basic unioned CTE with explicit columns' => [
'name' => 'cte',
'query' => (new SQLSelect([1, 2]))->addUnion(new SQLSelect(['3', '4']), SQLSelect::UNION_ALL),
'cteFields' => ['col1', 'col2'],
'recursive' => false,
'selectFields' => ['col1', 'col2'],
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [
['col1' => 1, 'col2' => 2],
['col1' => 3, 'col2' => 4],
],
],
// Recursive CTE with only one field in it
'basic recursive CTE with aliased columns' => [
'name' => 'cte',
'query' => (new SQLSelect(['str' => "CAST('abc' AS CHAR(20))"]))->addUnion(
new SQLSelect(['ignoredAlias' => 'CONCAT(str, str)'], 'cte', ['LENGTH(str) < 10']),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => true,
'selectFields' => '*',
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [
['str' => 'abc'],
['str' => 'abcabc'],
['str' => 'abcabcabcabc'],
],
],
'basic recursive CTE with explicit columns' => [
'name' => 'cte',
'query' => (new SQLSelect("CAST('abc' AS CHAR(20))"))->addUnion(
new SQLSelect('CONCAT(str, str)', 'cte', ['LENGTH(str) < 10']),
SQLSelect::UNION_ALL
),
'cteFields' => ['str'],
'recursive' => true,
'selectFields' => '*',
'selectFrom' => 'cte',
'extraManipulations' => [],
'expected' => [
['str' => 'abc'],
['str' => 'abcabc'],
['str' => 'abcabcabcabc'],
],
],
// More complex recursive CTE
'medium recursive CTE with aliased columns' => [
'name' => 'fibonacci',
'query' => (new SQLSelect(['n' => 1, 'fib_n' => 0, 'next_fib_n' => 1]))->addUnion(
new SQLSelect(['n + 1', 'next_fib_n', 'fib_n + next_fib_n'], 'fibonacci', ['n < 6']),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => true,
'selectFields' => '*',
'selectFrom' => 'fibonacci',
'extraManipulations' => [],
'expected' => [
['n' => 1, 'fib_n' => 0, 'next_fib_n' => 1],
['n' => 2, 'fib_n' => 1, 'next_fib_n' => 1],
['n' => 3, 'fib_n' => 1, 'next_fib_n' => 2],
['n' => 4, 'fib_n' => 2, 'next_fib_n' => 3],
['n' => 5, 'fib_n' => 3, 'next_fib_n' => 5],
['n' => 6, 'fib_n' => 5, 'next_fib_n' => 8],
],
],
// SQLSelect dedupes select fields. Because of that, for this test we have to start from a sequence
// that doesn't select duplicate values - otherwise we end up selecting "1, 0" instead of "1, 0, 1"
// in the main CTE select expression.
'medium recursive CTE with explicit columns' => [
'name' => 'fibonacci',
'query' => (new SQLSelect([3, 1, 2]))->addUnion(
new SQLSelect(['n + 1', 'next_fib_n', 'fib_n + next_fib_n'], 'fibonacci', ['n < 6']),
SQLSelect::UNION_ALL
),
'cteFields' => ['n', 'fib_n', 'next_fib_n'],
'recursive' => true,
'selectFields' => '*',
'selectFrom' => 'fibonacci',
'extraManipulations' => [],
'expected' => [
['n' => 3, 'fib_n' => 1, 'next_fib_n' => 2],
['n' => 4, 'fib_n' => 2, 'next_fib_n' => 3],
['n' => 5, 'fib_n' => 3, 'next_fib_n' => 5],
['n' => 6, 'fib_n' => 5, 'next_fib_n' => 8],
],
],
// Validate that we can have a CTE with multiple fields, while only using one field in the result set
'medium recursive CTE selecting only one column in the result' => [
'name' => 'fibonacci',
'query' => (new SQLSelect(['n' => 1, 'fib_n' => 0, 'next_fib_n' => 1]))->addUnion(
new SQLSelect(['n + 1', 'next_fib_n', 'fib_n + next_fib_n'], 'fibonacci', ['n < 6']),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => true,
'selectFields' => 'fib_n',
'selectFrom' => 'fibonacci',
'extraManipulations' => [],
'expected' => [
['fib_n' => 0],
['fib_n' => 1],
['fib_n' => 1],
['fib_n' => 2],
['fib_n' => 3],
['fib_n' => 5],
],
],
// Using an actual database table, extrapolate missing data with a recursive query
'complex recursive CTE with aliased columns' => [
'name' => 'dates',
'query' => (new SQLSelect(['date' => 'MIN("Date")'], "SQLSelectTestCteDates"))->addUnion(
new SQLSelect(
'date + INTERVAL 1 DAY',
'dates',
['date + INTERVAL 1 DAY <= (SELECT MAX("Date") FROM "SQLSelectTestCteDates")']
),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => true,
'selectFields' => ['dates.date', 'sum_price' => 'COALESCE(SUM("Price"), 0)'],
'selectFrom' => 'dates',
'extraManipulations' => [
'addLeftJoin' => ['SQLSelectTestCteDates', 'dates.date = "SQLSelectTestCteDates"."Date"'],
'addOrderBy' => ['dates.date'],
'addGroupBy' => ['dates.date'],
],
'expected' => [
['date' => '2017-01-03', 'sum_price' => 300],
['date' => '2017-01-04', 'sum_price' => 0],
['date' => '2017-01-05', 'sum_price' => 0],
['date' => '2017-01-06', 'sum_price' => 50],
['date' => '2017-01-07', 'sum_price' => 0],
['date' => '2017-01-08', 'sum_price' => 180],
['date' => '2017-01-09', 'sum_price' => 0],
['date' => '2017-01-10', 'sum_price' => 5],
],
],
'complex recursive CTE with explicit columns' => [
'name' => 'dates',
'query' => (new SQLSelect('MIN("Date")', "SQLSelectTestCteDates"))->addUnion(
new SQLSelect(
'date + INTERVAL 1 DAY',
'dates',
['date + INTERVAL 1 DAY <= (SELECT MAX("Date") FROM "SQLSelectTestCteDates")']
),
SQLSelect::UNION_ALL
),
'cteFields' => ['date'],
'recursive' => true,
'selectFields' => ['dates.date', 'sum_price' => 'COALESCE(SUM("Price"), 0)'],
'selectFrom' => 'dates',
'extraManipulations' => [
'addLeftJoin' => ['SQLSelectTestCteDates', 'dates.date = "SQLSelectTestCteDates"."Date"'],
'addOrderBy' => ['dates.date'],
'addGroupBy' => ['dates.date'],
],
'expected' => [
['date' => '2017-01-03', 'sum_price' => 300],
['date' => '2017-01-04', 'sum_price' => 0],
['date' => '2017-01-05', 'sum_price' => 0],
['date' => '2017-01-06', 'sum_price' => 50],
['date' => '2017-01-07', 'sum_price' => 0],
['date' => '2017-01-08', 'sum_price' => 180],
['date' => '2017-01-09', 'sum_price' => 0],
['date' => '2017-01-10', 'sum_price' => 5],
],
],
// Using an actual database table, get the ancestors of a given record with a recursive query
'complex hierarchical CTE with aliased columns' => [
'name' => 'hierarchy',
'query' => (
new SQLSelect(
['parent_id' => '"SQLSelectTestCteRecursive"."ParentID"'],
"SQLSelectTestCteRecursive",
[['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."Title" = ?' => 'child of child1']]
)
)->addUnion(
new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
// Note that we select both the CTE and the real table in the FROM statement.
// We could also select one of these and JOIN on the other.
['"hierarchy"', '"SQLSelectTestCteRecursive"'],
['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"']
),
SQLSelect::UNION_ALL
),
'cteFields' => [],
'recursive' => true,
'selectFields' => ['"SQLSelectTestCteRecursive"."Title"'],
'selectFrom' => '"SQLSelectTestCteRecursive"',
'extraManipulations' => [
'addInnerJoin' => ['hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"'],
],
'expected' => [
['Title' => 'child1'],
['Title' => 'parent'],
['Title' => 'grandparent'],
],
],
'complex hierarchical CTE with explicit columns' => [
'name' => 'hierarchy',
'query' => (
new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
"SQLSelectTestCteRecursive",
[['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."Title" = ?' => 'child of child1']]
)
)->addUnion(
new SQLSelect(
'"SQLSelectTestCteRecursive"."ParentID"',
['"hierarchy"', '"SQLSelectTestCteRecursive"'],
['"SQLSelectTestCteRecursive"."ParentID" > 0 AND "SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"']
),
SQLSelect::UNION_ALL
),
'cteFields' => ['parent_id'],
'recursive' => true,
'selectFields' => ['"SQLSelectTestCteRecursive"."Title"'],
'selectFrom' => '"SQLSelectTestCteRecursive"',
'extraManipulations' => [
'addInnerJoin' => ['hierarchy', '"SQLSelectTestCteRecursive"."ID" = "hierarchy"."parent_id"'],
],
'expected' => [
['Title' => 'child1'],
['Title' => 'parent'],
['Title' => 'grandparent'],
],
],
];
}
/**
* @dataProvider provideWith
*/
public function testWith(
string $name,
SQLSelect $query,
array $cteFields,
bool $recursive,
string|array $selectFields,
string|array $selectFrom,
array $extraManipulations,
array $expected
) {
if (!DB::get_conn()->supportsCteQueries()) {
$this->markTestSkipped('The current database does not support WITH statements');
}
if ($recursive && !DB::get_conn()->supportsCteQueries(true)) {
$this->markTestSkipped('The current database does not support recursive WITH statements');
}
$select = new SQLSelect($selectFields, $selectFrom);
$select->addWith($name, $query, $cteFields, $recursive);
foreach ($extraManipulations as $method => $args) {
$select->$method(...$args);
}
$this->assertEquals($expected, iterator_to_array($select->execute(), true));
}
/**
* Tests that we can have multiple WITH statements for a given SQLSelect object, and that
* subsequent WITH statements can refer to one another.
*/
public function testMultipleWith()
{
if (!DB::get_conn()->supportsCteQueries()) {
$this->markTestSkipped('The current database does not support WITH statements');
}
$cte1 = new SQLSelect('"SQLSelectTestCteDates"."Price"', "SQLSelectTestCteDates");
$cte2 = new SQLSelect('"SQLSelectTestCteRecursive"."Title"', "SQLSelectTestCteRecursive");
$cte3 = new SQLSelect(['price' => 'price', 'title' => 'title'], ['cte1', 'cte2']);
$select = new SQLSelect(['price', 'title'], 'cte3');
$select->addWith('cte1', $cte1, ['price'])
->addWith('cte2', $cte2, ['title'])
->addWith('cte3', $cte3)
->addOrderBy(['price', 'title']);
$expected = [];
foreach (CteDatesObject::get()->sort('Price') as $priceRecord) {
foreach (CteRecursiveObject::get()->sort('Title') as $titleRecord) {
$expected[] = [
'price' => $priceRecord->Price,
'title' => $titleRecord->Title,
];
}
}
$this->assertEquals($expected, iterator_to_array($select->execute(), true));
}
/**
* Tests that a second WITH clause with a duplicate name triggers an exception.
*/
public function testMultipleWithDuplicateName()
{
if (!DB::get_conn()->supportsCteQueries()) {
$this->markTestSkipped('The current database does not support WITH statements');
}
$select = new SQLSelect();
$select->addWith('cte', new SQLSelect());
$this->expectException(LogicException::class);
$this->expectExceptionMessage('WITH clause with name \'cte\' already exists.');
$select->addWith('cte', new SQLSelect());
}
}

View File

@ -9,3 +9,36 @@ SilverStripe\ORM\Tests\SQLSelectTest\TestObject:
Meta: 'Details 2'
Date: 2012-05-01 09:00:00
Common: 'Common Value'
SilverStripe\ORM\Tests\SQLSelectTest\CteDatesObject:
dates1:
Date: '2017-01-03'
Price: 300
dates2:
Date: '2017-01-06'
Price: 50
dates3:
Date: '2017-01-08'
Price: 180
dates4:
Date: '2017-01-10'
Price: 5
SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject:
recursive1:
Title: 'grandparent'
recursive2:
Title: 'parent'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.recursive1
recursive3:
Title: 'child1'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.recursive2
recursive4:
Title: 'child2'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.recursive2
recursive5:
Title: 'child of child1'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.recursive3
recursive6:
Title: 'child of child2'
Parent: =>SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject.recursive5

View File

@ -0,0 +1,16 @@
<?php
namespace SilverStripe\ORM\Tests\SQLSelectTest;
use SilverStripe\Dev\TestOnly;
use SilverStripe\ORM\DataObject;
class CteDatesObject extends DataObject implements TestOnly
{
private static $table_name = 'SQLSelectTestCteDates';
private static $db = [
'Date' => 'Date',
'Price' => 'Int',
];
}

View File

@ -0,0 +1,23 @@
<?php
namespace SilverStripe\ORM\Tests\SQLSelectTest;
use SilverStripe\Dev\TestOnly;
use SilverStripe\ORM\DataObject;
class CteRecursiveObject extends DataObject implements TestOnly
{
private static $table_name = 'SQLSelectTestCteRecursive';
private static $db = [
'Title' => 'Varchar',
];
private static $has_one = [
'Parent' => self::class,
];
private static $has_many = [
'Children' => self::class . '.Parent',
];
}