diff --git a/src/ORM/Connect/DBQueryBuilder.php b/src/ORM/Connect/DBQueryBuilder.php index c0f1e63f033..ba95196ac85 100644 --- a/src/ORM/Connect/DBQueryBuilder.php +++ b/src/ORM/Connect/DBQueryBuilder.php @@ -68,7 +68,8 @@ public function buildSQL(SQLExpression $query, &$parameters) */ protected function buildSelectQuery(SQLSelect $query, array &$parameters) { - $sql = $this->buildSelectFragment($query, $parameters); + $sql = $this->buildWithFragment($query, $parameters); + $sql .= $this->buildSelectFragment($query, $parameters); $sql .= $this->buildFromFragment($query, $parameters); $sql .= $this->buildWhereFragment($query, $parameters); $sql .= $this->buildGroupByFragment($query, $parameters); @@ -155,6 +156,38 @@ protected function buildUpdateQuery(SQLUpdate $query, array &$parameters) 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 .= $name; + + if (!empty($bits['cte_fields'])) { + $clause .= ' (' . implode(', ', $bits['cte_fields']) . ')'; + } + + $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. * diff --git a/src/ORM/Connect/Database.php b/src/ORM/Connect/Database.php index bd2084c8c39..94ab44bdacc 100644 --- a/src/ORM/Connect/Database.php +++ b/src/ORM/Connect/Database.php @@ -636,6 +636,24 @@ abstract public function searchEngine( $invertedMatch = false ); + /** + * Determines if this database support WITH statements. + * By default it is assumed that they don't unless they are explicitly enabled. + */ + public function supportsCteQueries(): bool + { + return false; + } + + /** + * Determines if this database support recursive WITH statements. + * By default it is assumed that they don't unless they are explicitly enabled. + */ + public function supportsRecursiveCteQueries(): bool + { + return false; + } + /** * Determines if this database supports transactions * @@ -654,7 +672,6 @@ public function supportsSavepoints() return false; } - /** * Determines if the used database supports given transactionMode as an argument to startTransaction() * If transactions are completely unsupported, returns false. diff --git a/src/ORM/Connect/MySQLDatabase.php b/src/ORM/Connect/MySQLDatabase.php index b80e02054b3..0dffaa4e415 100644 --- a/src/ORM/Connect/MySQLDatabase.php +++ b/src/ORM/Connect/MySQLDatabase.php @@ -313,6 +313,54 @@ public function searchEngine( return $list; } + public function supportsCteQueries(): bool + { + $version = $this->getVersion(); + $mariaDBVersion = $this->getMariaDBVersion($version); + if ($mariaDBVersion) { + // MariaDB has supported CTEs since 10.2.1 + // see https://mariadb.com/kb/en/mariadb-1021-release-notes/ + return $this->compareVersion($mariaDBVersion, '10.2.1') >= 0; + } + // MySQL has supported 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; + } + + public function supportsRecursiveCteQueries(): bool + { + $version = $this->getVersion(); + $mariaDBVersion = $this->getMariaDBVersion($version); + if ($mariaDBVersion) { + // MariaDB has supported Recursive CTEs since 10.2.2 + // see https://mariadb.com/kb/en/mariadb-1022-release-notes/ + return $this->compareVersion($mariaDBVersion, '10.2.2') >= 0; + } + // MySQL has supported Recursive 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. * diff --git a/src/ORM/DataQuery.php b/src/ORM/DataQuery.php index b37f1669938..1199a12c6cf 100644 --- a/src/ORM/DataQuery.php +++ b/src/ORM/DataQuery.php @@ -675,8 +675,6 @@ public function disjunctiveGroup() return new DataQuery_SubGroup($this, 'OR', $clause); } - - /** * Create a conjunctive subgroup * @@ -697,6 +695,57 @@ public function conjunctiveGroup() 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 one of DB::get_conn()->supportsCteQueries() + * or (for recursive queries) DB::get_conn()->supportsRecursiveCteQueries(). + * + * @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. + * @param string|string[] $onClause The "ON" clause (escaped SQL statement) for an INNER JOIN on the query. + * It can either be a full clause (like you would pass to {@link leftJoin()} or {@link innerJoin()}), + * or it can be an array mapping of the field(s) on the dataclass table that map with the field(s) on the CTE table + * e.g. ['ID' => 'cte_id'] + * If you want to use another join type, leave this blank and call the appropriate join method. + */ + public function with(string $name, self|SQLSelect $query, array $cteFields = [], string|array $onClause = '', 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) { + $selectFields = array_map(fn($colName) => $schema->sqlColumnForField($query->dataClass(), $colName), $cteFields); + $query = $query->query()->setSelect($selectFields); + } + + // Craft the "ON" clause for the join if we need to + if (is_array($onClause) && !empty($onClause)) { + $onClauses = []; + foreach ($onClause as $myField => $cteField) { + $onClauses[] = $schema->sqlColumnForField($this->dataClass(), $myField) . ' = ' . Convert::symbol2sql([$name, $cteField]); + } + $onClause = implode(' AND ', $onClauses); + } + + // Ensure all cte fields are escaped correctly + array_walk($cteFields, function ($colName) { + return preg_match('/^".*"$/', $colName) ? $colName : Convert::symbol2sql($colName); + }); + + // Add the WITH clause + $this->query->addWith(Convert::symbol2sql($name), $query, $cteFields, $recursive); + + // Only add a join if we have an ON clause, to allow developers to use their own alternative JOIN if they want to + if ($onClause) { + $this->query->addInnerJoin($name, $onClause); + } + + return $this; + } + /** * Adds a WHERE clause. * diff --git a/src/ORM/Queries/SQLSelect.php b/src/ORM/Queries/SQLSelect.php index fa38005aaf3..a1fa62ceba2 100644 --- a/src/ORM/Queries/SQLSelect.php +++ b/src/ORM/Queries/SQLSelect.php @@ -5,6 +5,7 @@ use SilverStripe\Core\Injector\Injector; use SilverStripe\ORM\DB; use InvalidArgumentException; +use LogicException; /** * Object representing a SQL SELECT query. @@ -12,7 +13,6 @@ */ class SQLSelect extends SQLConditionalExpression { - /** * An array of SELECT fields, keyed by an optional alias. * @@ -36,6 +36,18 @@ class SQLSelect extends SQLConditionalExpression */ protected $having = []; + /** + * 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, + * 'recursive' => boolean, + * ] + */ + protected array $with = []; + /** * If this is true DISTINCT will be added to the SQL. * @@ -529,6 +541,38 @@ public function getHavingParameterised(&$parameters) return $conditions; } + /** + * Adds a Common Table Expression (CTE), aka WITH clause. + * + * Use of this method should usually be within a conditional check against one of DB::get_conn()->supportsCteQueries() + * or (for recursive queries) DB::get_conn()->supportsRecursiveCteQueries(). + * + * @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, self $query, array $cteFields = [], bool $recursive = false): static + { + if (array_key_exists($name, $this->with)) { + throw new LogicException("With statement 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. * diff --git a/tests/php/ORM/DataQueryTest.php b/tests/php/ORM/DataQueryTest.php index 34ae7619d6b..8a502021643 100644 --- a/tests/php/ORM/DataQueryTest.php +++ b/tests/php/ORM/DataQueryTest.php @@ -6,6 +6,8 @@ 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; @@ -16,6 +18,7 @@ class DataQueryTest extends SapphireTest protected static $extra_dataobjects = [ DataQueryTest\DataObjectAddsToQuery::class, + DataQueryTest\DateAndPriceObject::class, DataQueryTest\ObjectA::class, DataQueryTest\ObjectB::class, DataQueryTest\ObjectC::class, @@ -535,4 +538,163 @@ public function testExistsCreatesFunctionalQueries() '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'], + 'onClause' => ['ID' => 'cte_id'], + 'recursive' => false, + 'extraManipulations' => [], + 'expectedItems' => [ + 'fixtures' => [ + 'obj4', + 'obj5', + ], + ], + ], + 'naive CTE query with string join' => [ + 'dataClass' => DataQueryTest\DateAndPriceObject::class, + 'name' => 'cte', + 'query' => new SQLSelect('200'), + 'cteFields' => ['value'], + 'onClause' => '"DataQueryTest_DateAndPriceObject"."Price" < "cte"."value"', + 'recursive' => false, + 'extraManipulations' => [], + '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'], + 'onClause' => '"DataQueryTest_DateAndPriceObject"."Date" = "cte"."MyDate"', + 'recursive' => false, + 'extraManipulations' => [], + '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'], + 'onClause' => [], + 'recursive' => true, + 'extraManipulations' => [ + 'selectField' => ['COALESCE("DataQueryTest_DateAndPriceObject"."Date", "dates"."Date")', 'Date'], + 'setAllowCustomCollisions' => [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'], + ] + ], + ], + // @TODO add hierarchy test as well to ensure we can filter by more fields in the CTEs than we need as CTE fields. + // @TODO add a test that has multiple ON clauses in an array + // @TODO add a test that depends on the DataQuery being passed in having all its appropriate joins (e.g. by having a WHERE something on a relation) + ]; + } + + /** + * @dataProvider provideWith + */ + public function testWith( + string $dataClass, + string $name, + string|SQLSelect $query, + array $cteFields, + string|array $onClause, + bool $recursive, + array $extraManipulations, + array $expectedItems + ) { + if (!DB::get_conn()->supportsCteQueries()) { + $this->markTestSkipped('The current database does not support WITH statements'); + } + if ($recursive && !DB::get_conn()->supportsRecursiveCteQueries()) { + $this->markTestSkipped('The current database does not support recursive WITH statements'); + } + + // 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, $onClause, $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))); + } + } } diff --git a/tests/php/ORM/DataQueryTest.yml b/tests/php/ORM/DataQueryTest.yml index e6e8dc1775e..b16e6c05214 100644 --- a/tests/php/ORM/DataQueryTest.yml +++ b/tests/php/ORM/DataQueryTest.yml @@ -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,23 @@ 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' diff --git a/tests/php/ORM/DataQueryTest/DateAndPriceObject.php b/tests/php/ORM/DataQueryTest/DateAndPriceObject.php new file mode 100644 index 00000000000..113aa409619 --- /dev/null +++ b/tests/php/ORM/DataQueryTest/DateAndPriceObject.php @@ -0,0 +1,16 @@ + 'Date', + 'Price' => 'Int', + ]; +} diff --git a/tests/php/ORM/SQLSelectTest.php b/tests/php/ORM/SQLSelectTest.php index be70ccb3a93..a900088aae7 100755 --- a/tests/php/ORM/SQLSelectTest.php +++ b/tests/php/ORM/SQLSelectTest.php @@ -3,12 +3,16 @@ namespace SilverStripe\ORM\Tests; use InvalidArgumentException; +use mysqli_sql_exception; 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\Connect\DatabaseException; +use SilverStripe\ORM\Tests\SQLSelectTest\CteDatesObject; +use SilverStripe\ORM\Tests\SQLSelectTest\CteRecursiveObject; class SQLSelectTest extends SapphireTest { @@ -18,7 +22,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; @@ -73,13 +79,36 @@ public function testEmptyQueryReturnsNothing() $this->assertSQLEquals('', $query->sql($parameters)); } - public function testSelectFromBasicTable() + public function provideSelectFrom() + { + return [ + [ + 'from' => ['MyTable'], + 'expected' => 'SELECT * FROM MyTable', + ], + [ + 'from' => ['MyTable', 'MySecondTable'], + 'expected' => 'SELECT * FROM MyTable, MySecondTable', + ], + [ + 'from' => ['MyTable', 'INNER JOIN AnotherTable on AnotherTable.ID = MyTable.SomeFieldID'], + 'expected' => 'SELECT * FROM MyTable INNER JOIN AnotherTable on AnotherTable.ID = MyTable.SomeFieldID', + ], + [ + 'from' => ['MyTable', 'MySecondTable', 'INNER JOIN AnotherTable on AnotherTable.ID = MyTable.SomeFieldID'], + 'expected' => 'SELECT * FROM MyTable, MySecondTable INNER JOIN AnotherTable on AnotherTable.ID = MyTable.SomeFieldID', + ], + ]; + } + + /** + * @dataProvider provideSelectFrom + */ + public function testSelectFrom(array $from, string $expected) { $query = new SQLSelect(); - $query->setFrom('MyTable'); - $this->assertSQLEquals("SELECT * FROM MyTable", $query->sql($parameters)); - $query->addFrom('MyJoin'); - $this->assertSQLEquals("SELECT * FROM MyTable MyJoin", $query->sql($parameters)); + $query->setFrom($from); + $this->assertSQLEquals($expected, $query->sql($parameters)); } public function testSelectFromUserSpecifiedFields() @@ -814,19 +843,359 @@ public function testBaseTableAliases() $sql ); - // This feature is a bug that used to exist in SS4 and was removed in SS5 - // so now we test it does not exist and we end up with incorrect SQL because of that - // In SS4 the "explicitAlias" would be ignored + // Ensure that explicit aliases as array keys are always respected, even if there was already an alias in the array value. $query = SQLSelect::create('*', [ 'MyTableAlias' => '"MyTable"', - 'explicitAlias' => ', (SELECT * FROM "MyTable" where "something" = "whatever") as "CrossJoin"' + 'explicitAlias' => '(SELECT * FROM "MyTable" where "something" = "whatever") as "CrossJoin"' ]); $sql = $query->sql(); $this->assertSQLEquals( - 'SELECT * FROM "MyTable" AS "MyTableAlias" , ' . + 'SELECT * FROM "MyTable" AS "MyTableAlias", ' . '(SELECT * FROM "MyTable" where "something" = "whatever") as "CrossJoin" AS "explicitAlias"', $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], + ], + ], + 'medium recursive CTE with explicit columns' => [ + 'name' => 'fibonacci', + 'query' => (new SQLSelect([1, 0, 1]))->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' => [], + // SQLSelect dedupes select fields. Unless that changes this will result in a database exception + // because we end up selecting "1, 0" instead of "1, 0, 1" in the main CTE select expression. + 'expected' => DatabaseException::class, + ], + // 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'], + ], + ], + // @TODO add a test with a second WITH with a duplicate name, which triggers LogicException + ]; + } + + /** + * @dataProvider provideWith + */ + public function testWith( + string $name, + SQLSelect $query, + array $cteFields, + bool $recursive, + string|array $selectFields, + string|array $selectFrom, + array $extraManipulations, + string|array $expected + ) { + if (!DB::get_conn()->supportsCteQueries()) { + $this->markTestSkipped('The current database does not support WITH statements'); + } + if ($recursive && !DB::get_conn()->supportsRecursiveCteQueries()) { + $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); + } + + if (is_string($expected)) { + $this->expectException($expected); + $select->execute(); + } else { + $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)); + } } diff --git a/tests/php/ORM/SQLSelectTest.yml b/tests/php/ORM/SQLSelectTest.yml index 66f52b34fe8..bde5728bcdf 100644 --- a/tests/php/ORM/SQLSelectTest.yml +++ b/tests/php/ORM/SQLSelectTest.yml @@ -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 diff --git a/tests/php/ORM/SQLSelectTest/CteDatesObject.php b/tests/php/ORM/SQLSelectTest/CteDatesObject.php new file mode 100644 index 00000000000..d35ea39e531 --- /dev/null +++ b/tests/php/ORM/SQLSelectTest/CteDatesObject.php @@ -0,0 +1,16 @@ + 'Date', + 'Price' => 'Int', + ]; +} diff --git a/tests/php/ORM/SQLSelectTest/CteRecursiveObject.php b/tests/php/ORM/SQLSelectTest/CteRecursiveObject.php new file mode 100644 index 00000000000..6423b2e12d1 --- /dev/null +++ b/tests/php/ORM/SQLSelectTest/CteRecursiveObject.php @@ -0,0 +1,23 @@ + 'Varchar', + ]; + + private static $has_one = [ + 'Parent' => self::class, + ]; + + private static $has_many = [ + 'Children' => self::class . '.Parent', + ]; +}