diff --git a/src/ORM/Connect/DBQueryBuilder.php b/src/ORM/Connect/DBQueryBuilder.php index c0f1e63f033..ed493609b9a 100644 --- a/src/ORM/Connect/DBQueryBuilder.php +++ b/src/ORM/Connect/DBQueryBuilder.php @@ -68,13 +68,24 @@ public function buildSQL(SQLExpression $query, &$parameters) */ 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->buildWithFragment($query, $parameters); + $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; } @@ -155,6 +166,66 @@ protected function buildUpdateQuery(SQLUpdate $query, array &$parameters) return $sql; } + 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 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. * @@ -242,9 +313,25 @@ public function buildUpdateFragment(SQLUpdate $query, array &$parameters) public function buildFromFragment(SQLConditionalExpression $query, array &$parameters) { $from = $query->getJoins($joinParameters); + $tables = []; + $joins = []; + + // E.g. a naive "Select 1" statemnt is valid SQL + if (empty($from)) { + return ''; + } + + foreach ($from as $joinOrTable) { + if (preg_match(SQLConditionalExpression::JOIN_REGEX, $joinOrTable)) { + $joins[] = $joinOrTable; + } else { + $tables[] = $joinOrTable; + } + } + $parameters = array_merge($parameters, $joinParameters); $nl = $this->getSeparator(); - return "{$nl}FROM " . implode(' ', $from); + return "{$nl}FROM " . implode(', ', $tables) . ' ' . implode(' ', $joins); } /** 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/DataList.php b/src/ORM/DataList.php index 1392933c4bd..4217f7f903c 100644 --- a/src/ORM/DataList.php +++ b/src/ORM/DataList.php @@ -15,6 +15,7 @@ use SilverStripe\ORM\DataQuery; use SilverStripe\ORM\ArrayList; use SilverStripe\ORM\Filters\SearchFilterable; +use SilverStripe\ORM\Queries\SQLSelect; /** * Implements a "lazy loading" DataObjectSet. @@ -313,6 +314,52 @@ public function canFilterBy($fieldName) return false; } + // @TODO is there a case where we want recursiveFilterAny? Or recursiveExclude/Any? Or recursiveWhere? Or some combination of those? + // @TODO is there a case where we want to sort the recursive or base portion, and grab the first of many possible matches? + // In the case of recursiveWhere that's probably getting into "just use alterDataQuery" territory + // .... Are we getting to the point where we'd be better off passing in lists or callables, to allow the full power of the DataList API? + // @TODO is there a case where we want to sort the resultset by some field from the WITH clause? + public function recursiveFilter(array $baseFilters, array $recursiveFilters) + { + $schema = DataObject::getSchema(); + $baseFields = []; + foreach ($baseFilters as $filter => $value) { + $fieldArgs = explode(':', $filter); + $baseFields[] = $schema->sqlColumnForField($this->dataClass(), array_shift($fieldArgs)); + } + $recursiveFields = []; + foreach ($recursiveFilters as $filter => $value) { + $fieldArgs = explode(':', $filter); + $recursiveFields[] = $schema->sqlColumnForField($this->dataClass(), array_shift($fieldArgs)); + } + + $queryFields = array_intersect($baseFields, $recursiveFields); + + + $cteName = 'CTE_Ancestor'; // @TODO dynamically generate a name, and make sure it can handle multiple recursive filters per list + // @TODO we need a better way to generate these - or just pass them in + // @TODO is there a case where we'd want multiple args for the recursive query? Or something other than ID? + // For example, https://learnsql.com/blog/get-to-know-the-power-of-sql-recursive-queries/ has an example where three args are used, + // one of which is "is_visited" which is only used in the recursive portion, and is used to avoid double-checking items. + // One way to handle this would be to have a third set of filters, which is only for additional filters that are _only_ required for the special thingy. + // We could then derive the args from that - but in that case we'd need some way to tell which ones need to be part of the join.... + $cteIdField = 'cte_id'; + $yy = "\"$cteName\".\"$cteIdField\""; + // @TODO This WHERE is obviously not ideal. + // @TODO is there a case where we want something other than ID (see args above)? + // We may need a third argument to hold this part - but we need to make sure to abstract it in an appropriate way. + $idField = $schema->sqlColumnForField($this->dataClass(), 'ID'); + $recursiveQuery = self::create($this->dataClass())->filter($recursiveFilters)->where("$idField = $yy")->sort(null)->dataQuery(); + $recursiveQuery->innerJoin($cteName, $idField . ' = ' . $yy)->distinct(false); + $recursiveQuery = $recursiveQuery->query()->setSelect($queryFields); + $baseQuery = self::create($this->dataClass())->filter($baseFilters)->sort(null)->dataQuery(); + $baseQuery->union($recursiveQuery); + $baseQuery = $baseQuery->query()->setSelect($queryFields); + return $this->alterDataQuery(function (DataQuery $query) use ($baseQuery, $cteName, $cteIdField) { + $query->with($cteName, $baseQuery, ["\"$cteIdField\""], ['ID' => $cteIdField], true); + }); + } + /** * Return a new DataList instance with the records returned in this query * restricted by a limit clause. diff --git a/src/ORM/DataQuery.php b/src/ORM/DataQuery.php index b37f1669938..d6fb761fe5f 100644 --- a/src/ORM/DataQuery.php +++ b/src/ORM/DataQuery.php @@ -655,6 +655,15 @@ public function having($having) return $this; } + public function union(self|SQLSelect $query, ?string $type = null): static + { + if ($query instanceof self) { + $query = $query->query(); + } + $this->query->addUnion($query, $type); + return $this; + } + /** * Create a disjunctive subgroup. * @@ -697,6 +706,58 @@ public function conjunctiveGroup() return new DataQuery_SubGroup($this, 'AND', $clause); } + /** + * @TODO Add PHPDoc - including union is required for recursive queries, and can't be distinct and the term "CTE" + * + * @param string|array $onClause The "ON" clause (escaped SQL statement) for joining 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'] + */ + public function with(string $name, self|SQLSelect $query, array $cteFields = [], string|array $onClause = '', bool $recursive = false): static + { + // If the query is a DataQuery, make sure all manipulators, joins, etc are applied + // @TODO craft a unit test that protects against this being swapped to $query = $query->query; + // or validate that the existing tests already do that + if ($query instanceof self) { + $query = $query->query(); + } + + $quotedName = '"' . $name . '"'; + + // Craft the "ON" clause for the join if we need to + if (is_array($onClause) && !empty($onClause)) { + $schema = DataObject::getSchema(); + $onClauses = []; + foreach ($onClause as $myField => $cteField) { + $onClauses[] = $schema->sqlColumnForField($this->dataClass(), $myField) . " = $quotedName.\"$cteField\""; + } + $onClause = implode(' AND ', $onClauses); + } + + // // Recursive portion can't be distinct, and must include the with cte_name as FROM like it's a table + // $recursiveQuery->addFrom($quotedName)->setDistinct(false); + // // @TODO ew. How do I pass the field(s) in? + // // Needed for the DataList abstraction, since leaving these out results in + // // "Unknown column 'Ancestor.pid' in 'where clause'"... not sure why this fixes it though? + // $baseQuery->setSelect('"ParentID"'); + // $recursiveQuery->setSelect('"ParentID"'); + // @TODO do I still need those? If not, do those requirements need to at least be documented somewhere? + + // Add the WITH + // @TODO should I be automagically quoting the field names here? + // @TODO Or should they be automagically quoted in SQLSelect? + $this->query->addWith($quotedName, $query, $cteFields, $recursive); + + // Only add a join if we have an on clause + // Sometimes people will want to use a CTE as a subquery which could be referenced in a WHERE or similar. + if ($onClause) { + $this->query->addInnerJoin($name, $onClause); + } + + return $this; + } + /** * Adds a WHERE clause. * diff --git a/src/ORM/Hierarchy/Hierarchy.php b/src/ORM/Hierarchy/Hierarchy.php index e1c4bb42fd5..dcd0e071eba 100644 --- a/src/ORM/Hierarchy/Hierarchy.php +++ b/src/ORM/Hierarchy/Hierarchy.php @@ -16,6 +16,9 @@ use SilverStripe\Core\Config\Config; use SilverStripe\Core\Convert; use Exception; +use SilverStripe\CMS\Model\SiteTree; +use SilverStripe\ORM\DataQuery; +use SilverStripe\ORM\Queries\SQLSelect; use SilverStripe\View\ViewableData; /** @@ -540,13 +543,115 @@ public function getParent($filter = null) public function getAncestors($includeSelf = false) { $ancestors = new ArrayList(); - $object = $this->owner; if ($includeSelf) { - $ancestors->push($object); + $ancestors->push($this->owner); } - while ($object = $object->getParent()) { - $ancestors->push($object); + + $parentID = $this->owner->ParentID; + if (empty($parentID)) { + return $ancestors; + } + + if (!DB::get_conn()->supportsRecursiveCteQueries()) { + $object = $this->owner; + while ($object = $object->getParent()) { + $ancestors->push($object); + } + return $ancestors; + } + + // @TODO Make a DataQuery API for this + // probably automatically named alias? + // Not sure how abstract we need to make the base and recursive queries - maybe base can accept DataQuery? + // @TODO Make a DataList API for this + // Allow filtering and sorting by the recursive table fields (args) + // Not sure how abstract we need to make the base and recursive queries - maybe base can accept DataList? + // @TODO Ensure this specific implementation is compatible with getParent() + // @TODO mysql 5.7 doesn't support WITH RECURSIVE.... do we stop supporting it? Or can we have a IF 5.7 DO X ELSE DO Y? + // Don't worry about that just yet, though. Get it working with this syntax in a clean generalised way first. + // @TODO fix broken builds + // SEE https://github.com/GuySartorelli/silverstripe-framework/actions/runs/5758157653/job/15610259235 for when it was a raw DB::query + // SEE https://github.com/GuySartorelli/silverstripe-framework/actions/runs/5758790963 for any failures in a post-SQLSelect world + // @TODO tests + // For the SQLSelect tests, ensure we can select from the recursion table directly, not just select from the actual db table + + // RAW SQL version + // $rows = DB::query( + // << 0 AND ID = {$this->owner->ID} + // UNION ALL + // -- Recursively fetch ancestors - stop when there are no more parent IDs to look at + // SELECT ParentID FROM CTE_Ancestor, {$table} + // WHERE ParentID > 0 AND ID = CTE_Ancestor.pid + // ) + // -- Get records where the ancestor pid matches an ID in the base table - getting me all ancestors + // -- which means any pid where the parent was deleted won't return a record + // -- @TODO if it DOESN'T match, that's what I care about here. + // SELECT * FROM {$table} + // INNER JOIN CTE_Ancestor ON ID = CTE_Ancestor.pid + // SQL + // ); + + $ownerClass = get_class($this->owner); + + // SQLSelect version + // $table = '"' . DataObject::getSchema()->tableForField($ownerClass, 'ParentID') . '"'; + // $recursiveQuery = SQLSelect::create('"ParentID"', ['"CTE_Ancestor"', $table], ['"ParentID" > 0 AND "ID" = "CTE_Ancestor"."pid"']); + // $query = SQLSelect::create('"ParentID"', $table, [['"ParentID" > 0 AND "ID" = ?' => $this->owner->ID]]) + // ->addUnion($recursiveQuery, SQLSelect::UNION_ALL); + // $rows = SQLSelect::create(from: $table)->addInnerJoin('CTE_Ancestor', '"ID" = "CTE_Ancestor"."pid"') + // ->addWith('"CTE_Ancestor"', $query, ['"pid"'], true) + // ->execute(); + // $list = DataList::create($ownerClass); + // $records = []; + // foreach ($rows as $row) { + // $records[] = $list->createDataObject($row); + // } + + + // DataQuery version + /** @var DataList $records */ + // $records = DataList::create($ownerClass)->alterDataQuery(function(DataQuery $query) use ($ownerClass) { + // $table = '"' . DataObject::getSchema()->tableForField($ownerClass, 'ParentID') . '"'; + // $field = DataObject::getSchema()->sqlColumnForField($ownerClass, 'ParentID'); + // $recursiveQuery = SQLSelect::create('"ParentID"', ['"CTE_Ancestor"', $table], ['"ParentID" > 0 AND "ID" = "CTE_Ancestor"."pid"']); + // // $recursiveQuery = SQLSelect::create($field, ['"CTE_Ancestor"', $table], [$field . ' > 0 AND ' . $table . '."ID" = "CTE_Ancestor"."pid"']); + // $baseQuery = SQLSelect::create('"ParentID"', $table, [['"ParentID" > 0 AND "ID" = ?' => $this->owner->ID]]) + // ->addUnion($recursiveQuery, SQLSelect::UNION_ALL); + // // $baseQuery = DataList::create($ownerClass)->filter(['ParentID:GreaterThan' => 0, 'ID' => $this->owner->ID])->dataQuery() + // // ->union($recursiveQuery, SQLSelect::UNION_ALL); + // $query->with('CTE_Ancestor', $baseQuery, ['ID' => 'pid'], ['"pid"'], true); + // }); + + // var_dump($records->sql()); + + // $records = DataList::create($ownerClass)->alterDataQuery(function(DataQuery $query) use ($ownerClass) { + // $table = '"' . DataObject::getSchema()->tableForField($ownerClass, 'ParentID') . '"'; + // $field = DataObject::getSchema()->sqlColumnForField($ownerClass, 'ParentID'); + // $recursiveQuery = SQLSelect::create($field, ['"CTE_Ancestor"', $table], [$field . ' > 0 AND ' . $table . '."ID" = "CTE_Ancestor"."pid"']); + // $baseQuery = DataList::create($ownerClass)->filter(['ParentID:GreaterThan' => 0, 'ID' => $this->owner->ID])->dataQuery()->distinct(false) + // ->union($recursiveQuery, SQLSelect::UNION_ALL); + // // $baseQuery = $baseQuery->query()->setSelect('"ParentID"'); + // $query->with('CTE_Ancestor', $baseQuery, ['pid'], ['ID' => 'pid'], true); + // }); + + // var_dump($records->sql());die(); + + // DataList version + $records = DataList::create($ownerClass)->recursiveFilter([ + 'ID' => $this->owner->ID, + 'ParentID:GreaterThan' => 0 + ], [ + 'ParentID:GreaterThan' => 0 + ])->sort(null); + + // var_dump($records->sql());die(); + + foreach ($records as $record) { + $ancestors->push($record); } return $ancestors; diff --git a/src/ORM/Queries/SQLConditionalExpression.php b/src/ORM/Queries/SQLConditionalExpression.php index 55d6ae5c297..c694308f446 100644 --- a/src/ORM/Queries/SQLConditionalExpression.php +++ b/src/ORM/Queries/SQLConditionalExpression.php @@ -2,12 +2,15 @@ namespace SilverStripe\ORM\Queries; +use LogicException; + /** * Represents a SQL query for an expression which interacts with existing rows * (SELECT / DELETE / UPDATE) with a WHERE clause */ abstract class SQLConditionalExpression extends SQLExpression { + public const JOIN_REGEX = '/JOIN +.*? +(AS|ON|USING\(?) +/i'; /** * An array of WHERE clauses. @@ -226,7 +229,7 @@ public function queriedTables() foreach ($this->from as $key => $tableClause) { if (is_array($tableClause)) { $table = '"' . $tableClause['table'] . '"'; - } elseif (is_string($tableClause) && preg_match('/JOIN +("[^"]+") +(AS|ON) +/i', $tableClause ?? '', $matches)) { + } elseif (is_string($tableClause) && preg_match(self::JOIN_REGEX, $tableClause ?? '', $matches)) { $table = $matches[1]; } else { $table = $tableClause; @@ -325,11 +328,16 @@ protected function getOrderedJoins($from) return $from; } - // shift the first FROM table out from so we only deal with the JOINs - reset($from); - $baseFromAlias = key($from ?? []); - $baseFrom = array_shift($from); + // Remove the regular FROM tables out so we only deal with the JOINs + $regularTables = []; + foreach ($from as $alias => $tableClause) { + if (is_string($tableClause) && !preg_match(self::JOIN_REGEX, $tableClause)) { + $regularTables[$alias] = $tableClause; + unset($from[$alias]); + } + } + // Sort the joins $this->mergesort($from, function ($firstJoin, $secondJoin) { if (!is_array($firstJoin) || !is_array($secondJoin) @@ -341,11 +349,14 @@ protected function getOrderedJoins($from) } }); - // Put the first FROM table back into the results - if (!empty($baseFromAlias) && !is_numeric($baseFromAlias)) { - $from = array_merge([$baseFromAlias => $baseFrom], $from); - } else { - array_unshift($from, $baseFrom); + // Put the regular FROM tables back into the results + $regularTables = array_reverse($regularTables, true); + foreach ($regularTables as $alias => $tableName) { + if (!empty($alias) && !is_numeric($alias)) { + $from = array_merge([$alias => $tableName], $from); + } else { + array_unshift($from, $tableName); + } } return $from; diff --git a/src/ORM/Queries/SQLSelect.php b/src/ORM/Queries/SQLSelect.php index fa38005aaf3..7e196693ab3 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,6 +13,9 @@ */ 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,22 @@ class SQLSelect extends SQLConditionalExpression */ protected $having = []; + /** + * An array of subqueries to union with this one. + */ + protected array $union = []; + + /** + * An array of WITH clauses. + * This array is indexed with the WITH Name, and contains data in the following format: + * [ + * 'args' => string[], + * 'baseQuery' => ?SQLSelect, + * 'recursiveQuery' => ?SQLSelect, + * ] + */ + protected array $with = []; + /** * If this is true DISTINCT will be added to the SQL. * @@ -529,6 +549,56 @@ public function getHavingParameterised(&$parameters) 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 plain union + */ + 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.'); + } + + $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; + } + + /** + * @TODO Explain what this is and how it works. Include the term CTE + * Explain that a recursive query must have at least one union. + * Explain that the cteFields can be referenced from the union in the recursive query + * Explain what the cteFields do (if anything) in a non-recursive query + * + * @param string $name @TODO Probably explain this too! + * @param array $cteFields @TODO Add an explanation of what this IS + */ + public function addWith(string $name, SQLSelect $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; + } + + 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..569c0633d87 100644 --- a/tests/php/ORM/DataQueryTest.php +++ b/tests/php/ORM/DataQueryTest.php @@ -6,6 +6,7 @@ use SilverStripe\ORM\DataObject; use SilverStripe\ORM\DB; use SilverStripe\Dev\SapphireTest; +use SilverStripe\ORM\Queries\SQLSelect; use SilverStripe\ORM\Tests\DataQueryTest\ObjectE; use SilverStripe\Security\Member; @@ -16,6 +17,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 +537,139 @@ public function testExistsCreatesFunctionalQueries() 'exist is false when a limit returns no results' ); } + + public function provideWith() + { + return [ + 'naive CTE query with 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' => [], + 'expectedFixtures' => [ + 'obj4', + 'obj5', + ], + ], + 'naive CTE query without join' => [ + 'dataClass' => DataQueryTest\DateAndPriceObject::class, + 'name' => 'cte', + 'query' => new SQLSelect( + ['RANGE()'], + '"DataQueryTest_DateAndPriceObject"', + ['"DataQueryTest_DateAndPriceObject"."Price" > 200'] + ), + 'cteFields' => ['value'], + 'onClause' => [], + 'recursive' => false, + 'extraManipulations' => [], + 'expectedFixtures' => [ + ], + ], + ]; + } + +/* + +// Validate that we can have a CTE with multiple fields, while only using one field in the result set +// Add a "WHERE" referencing the CTE, so that we are using the CTE purely to generate data for the main query +'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 +// Missing data will be returned as records with no ID +'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], + ], +], + + +Include a test with a multi-item array onclause +Include a test with a string onclause +*/ + + /** + * @dataProvider provideWith + */ + public function testWith( + string $dataClass, + string $name, + DataQuery|SQLSelect $query, + array $cteFields, + string|array $onClause, + bool $recursive, + array $extraManipulations, + array $expectedFixtures + ) { + 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'); + } + + $dataQuery = new DataQuery($dataClass); + $dataQuery->with($name, $query, $cteFields, $onClause, $recursive); + + foreach ($extraManipulations as $method => $args) { + $dataQuery->$method(...$args); + } + + $expected = []; + foreach ($expectedFixtures as $fixtureName) { + $expected[] = $this->idFromFixture($dataClass, $fixtureName); + } + $this->assertEquals($expected, $dataQuery->execute()->column('ID')); + } } diff --git a/tests/php/ORM/DataQueryTest.yml b/tests/php/ORM/DataQueryTest.yml index e6e8dc1775e..6459f02d095 100644 --- a/tests/php/ORM/DataQueryTest.yml +++ b/tests/php/ORM/DataQueryTest.yml @@ -41,3 +41,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-01' + obj3: + Price: 200 + Date: '2023-01-01' + obj4: + Price: 300 + Date: '2023-01-01' + obj5: + Price: 400 + Date: '2023-01-01' 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..8a62a5bee3e 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,358 @@ 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'], + ], + ], + ]; + } + + /** + * @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', + ]; +}