Skip to content

Commit

Permalink
DOC Document ORM changes for CMS 5.2 (#351)
Browse files Browse the repository at this point in the history
  • Loading branch information
GuySartorelli authored Oct 2, 2023
1 parent 18b2e8d commit c6525f2
Show file tree
Hide file tree
Showing 3 changed files with 217 additions and 5 deletions.
82 changes: 78 additions & 4 deletions en/02_Developer_Guides/00_Model/01_Data_Model_and_ORM.md
Original file line number Diff line number Diff line change
Expand Up @@ -637,29 +637,99 @@ public function countDuplicates($model, $fieldToCheck)
}
```

### Common Table Expressions (CTEs aka the `WITH` clause) {#cte}

Common Table Expressions are a powerful tool both for optimising complex queries, and for creating recursive queries. You can use these by calling the [`DataQuery::with()`](api:SilverStripe\ORM\DataQuery::with()) method.

Note that there is no direct abstraction for this on `DataList`, so you'll need to [modify the underlying `DataQuery`](#modifying-the-underlying-query) to apply a CTE to a `DataList`.

Older database servers don't support this functionality, and the core implementation is only valid for MySQL (though community modules may add support for other database connectors). You can esure this code will only be used when it's supported by wrapping it in a conditional call to [`DB::get_conn()->supportsCteQueries()`](api:SilverStripe\ORM\Connect\Database::supportsCteQueries()). See the [SQL Queries](/developer_guides/model/sql_select/#cte) documentation for more details.

The following example is the equivalent to the example in the [SQL Queries](/developer_guides/model/sql_select/#cte) documentation, except it is modifying the underlying query of a `DataList`. This means we are effectively filtering the `DataList` to include only records which are ancestors of the `$someRecord` record.

```php
use App\Model\ObjectWithParent;
use SilverStripe\Core\Convert;
use SilverStripe\ORM\DataObject;
use SilverStripe\ORM\DataQuery;
use SilverStripe\ORM\DB;

// Only use the CTE functionality if it is supported by the current database
if (DB::get_conn()->supportsCteQueries(true)) {
$ancestors = ObjectWithParent::get()->alterDataQuery(function (DataQuery $baseQuery) use ($someRecord) {
$schema = DataObject::getSchema();
$parentIdField = $schema->sqlColumnForField(ObjectWithParent::class, 'ParentID');
$idField = $schema->sqlColumnForField(ObjectWithParent::class, 'ID');
$cteIdField = Convert::symbol2sql('hierarchy_cte.ParentID');

$cteQuery = new DataQuery(ObjectWithParent::class);
$cteQuery->where([
"$parentIdField > 0",
$idField => $someRecord->ID,
]);
$recursiveQuery = new DataQuery(ObjectWithParent::class);
$recursiveQuery->innerJoin('hierarchy_cte', "$idField = $cteIdField")
->where("$parentIdField > 0")
// MySQL doesn't support ORDER BY or DISTINCT in the recursive portion of a CTE
->sort(null)
->distinct(false);
$cteQuery->union($recursiveQuery);
$baseQuery->with('hierarchy_cte', $cteQuery, [], true);
$baseQuery->innerJoin('hierarchy_cte', "$idField = $cteIdField");
// This query result will include only the ancestors of whatever record is stored in the $someRecord variable.
return $baseQuery;
});
} else {
// provide an alternative implementation, e.g. a recursive PHP method which runs a query at each iteration
}
```

The PHPDoc for the [`DataQuery::with()`](api:SilverStripe\ORM\DataQuery::with()) method has more details about what each of the arguments are and how they're used, though note that you should ensure you understand the underlying SQL concept of CTE queries before using this API.

#### Gotchas {#cte-gotchas}

There are a few things that might catch you off guard with this abstraction if you aren't looking for them. Many of these are specifically enforced by MySQL and may not apply to other databases.

* `DataQuery` wants to use `DISTINCT` and to apply a sort order by default. MySQL 8 doesn't support `ORDER BY`, `DISTINCT`, or `LIMIT` in the recursive query block of Common Table Expressions so we need to make sure to explicitly set the sort order to null and distinct to false when using a `DataQuery` for that part of the query.
* If you use `DataQuery` for `$cteQuery` (i.e. the `$query` argument of the `with()` method), you can reduce the fields being selected by including them in the `$cteFields` argument. Be aware though that the number of fields passed in must match the number used in the recursive query if your CTE is recursive.
* `$cteFields` will be used to set the select fields for the `$cteQuery` if it's a `DataQuery` - but if it's a `SQLSelect` then this argument works the same as it does with `SQLSelect::addWith()`.

### Raw SQL

Occasionally, the system described above won't let you do exactly what you need to do. In these situations, we have
methods that manipulate the SQL query at a lower level. When using these, please ensure that all table and field names
are escaped with double quotes, otherwise some database backends (e.g. [PostgreSQL](https://github.com/silverstripe/silverstripe-postgresql)) won't work.

#### Modifying the underlying query

Under the hood, query generation is handled by the [DataQuery](api:SilverStripe\ORM\DataQuery) class. This class provides more direct access
to certain SQL features that `DataList` abstracts away from you.
to certain SQL features that `DataList` abstracts away from you. You can modify the underlying `DataQuery` by calling
the [`alterDataQuery()`](api:SilverStripe\ORM\DataList::alterDataQuery()) method.

This can be useful for accessing abstractions that exist on the `DataQuery` layer but aren't available at the `DataList` layer.

```php
$members = Member::get()->alterDataQuery(function (DataQuery $query) {
return $query->union($anotherQuery);
});
```

#### Using raw SQL directly

In general, we advise against using these methods unless it's absolutely necessary. If the ORM doesn't do quite what
you need it to, you may also consider extending the ORM with new data types or filter modifiers

#### Where clauses
##### Where clauses

You can specify a WHERE clause fragment (that will be combined with other filters using AND) with the `where()` method:

```php
$members = Member::get()->where("\"FirstName\" = 'Sam'");
```

#### Joining Tables
##### Joining Tables

You can specify a join with the `innerJoin` and `leftJoin` methods. Both of these methods have the same arguments:
You can specify a join with the `innerJoin`, `leftJoin`, and `rightJoin` methods. All of these methods have the same arguments:

* The name of the table to join to.
* The filter clause for the join.
Expand All @@ -669,12 +739,16 @@ You can specify a join with the `innerJoin` and `leftJoin` methods. Both of the
// Without an alias
$members = Member::get()
->leftJoin("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\"");
$members = Member::get()
->rightJoin("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\"");
$members = Member::get()
->innerJoin("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\"");

// With an alias "Rel"
$members = Member::get()
->leftJoin("Group_Members", "\"Rel\".\"MemberID\" = \"Member\".\"ID\"", "Rel");
$members = Member::get()
->rightJoin("Group_Members", "\"Rel\".\"MemberID\" = \"Member\".\"ID\"", "Rel");
$members = Member::get()
->innerJoin("Group_Members", "\"Rel\".\"MemberID\" = \"Member\".\"ID\"", "Rel");
```
Expand Down
79 changes: 79 additions & 0 deletions en/02_Developer_Guides/00_Model/08_SQL_Select.md
Original file line number Diff line number Diff line change
Expand Up @@ -105,6 +105,9 @@ $sqlQuery->selectField('YEAR("Birthday")', 'Birthyear');
$joinOnClause = $schema->sqlColumnForField(Player::class, 'TeamID') . ' = ' . $schema->sqlColumnForField(Team::class, 'ID');
$sqlQuery->addLeftJoin($teamTableName, $joinOnClause);

// Combine another query using a union
$sqlQuery->addUnion($anotherSqlSelect, SQLSelect::UNION_ALL);

// There are methods for most SQL clauses, such as WHERE, ORDER BY, GROUP BY, etc
$sqlQuery->addWhere(['YEAR("Birthday") = ?' => 1982]);
// $sqlQuery->setOrderBy(...);
Expand Down Expand Up @@ -414,6 +417,82 @@ foreach (ClassInfo::subclassesFor(Product::class, includeBaseClass: false) as $c
```
[/hint]

### Common Table Expressions (CTEs aka the `WITH` clause) {#cte}

Common Table Expressions are a powerful tool both for optimising complex queries, and for creating recursive queries. You can use these by calling the [`SQLSelect::addWith()`](api:SilverStripe\ORM\Queries\SQLSelect::addWith()) method.

Older database servers don't support this functionality, and the core implementation is only valid for MySQL (though community modules may add support for other database connectors). If you are using this functionality in an open source module or a project that you can't guarantee the type and version of database being used, you should wrap the query in a condition checking if CTEs are supported. You can do that by calling [`DB::get_conn()->supportsCteQueries()`](api:SilverStripe\ORM\Connect\Database::supportsCteQueries()).

```php
if (DB::get_conn()->supportsCteQueries()) {
// Supports non-recursive CTE clause
} elseif (DB::get_conn()->supportsCteQueries(true)) {
// Supports recursive CTE clause
} else {
// No CTE support
}
```

For an example of how to use this abstraction and how powerful it is, here is an example query that recursively fetches the ancestors of a given record.

```php
use App\Model\ObjectWithParent;
use SilverStripe\Core\Convert;
use SilverStripe\ORM\DataObject;
use SilverStripe\ORM\DB;
use SilverStripe\ORM\Queries\SQLSelect;

$schema = DataObject::getSchema();
$tableName = Convert::symbol2sql($schema->baseDataTable(ObjectWithParent::class));
$parentIdField = $schema->sqlColumnForField(ObjectWithParent::class, 'ParentID');
$idField = $schema->sqlColumnForField(ObjectWithParent::class, 'ID');
$cteIdField = Convert::symbol2sql('hierarchy_cte.parent_id');

// Only use the CTE functionality if it is supported by the current database
if (DB::get_conn()->supportsCteQueries(true)) {
$baseQuery = SQLSelect::create()->setFrom($tableName);
$cteQuery = SQLSelect::create(
$parentIdField,
$tableName,
[
"$parentIdField > 0",
$idField => $someRecord->ID,
]
);
$recursiveQuery = SQLSelect::create(
$parentIdField,
['"hierarchy_cte"', $tableName],
[
"$parentIdField > 0",
"$idField = $cteIdField",
]
);
$cteQuery->addUnion($recursiveQuery);
$baseQuery->addWith('hierarchy_cte', $cteQuery, ['parent_id'], true)->addInnerJoin('hierarchy_cte', "$idField = $cteIdField");
// This query result will include only the ancestors of whatever record is stored in the $someRecord variable.
$ancestors = $baseQuery->execute();
} else {
// provide an alternative implementation, e.g. a recursive PHP method which runs a query at each iteration
}
```

The SQL for that query, in MySQL, would look something like this:

```sql
WITH RECURSIVE "hierarchy_cte" ("parent_id") AS (
(
SELECT "ObjectWithParent"."ParentID" FROM "ObjectWithParent"
WHERE ("ObjectWithParent"."ParentID" > 0) AND ("ObjectWithParent"."ID" = ?)
) UNION (
SELECT "ObjectWithParent"."ParentID" FROM "hierarchy_cte", "ObjectWithParent"
WHERE ("ObjectWithParent"."ParentID" > 0) AND ("ObjectWithParent"."ID" = "hierarchy_cte"."parent_id")
)
)
SELECT * FROM "ObjectWithParent" INNER JOIN "hierarchy_cte" ON "ObjectWithParent"."ID" = "hierarchy_cte"."parent_id"
```

The PHPDoc for the [`SQLSelect::addWith()`](api:SilverStripe\ORM\Queries\SQLSelect::addWith()) method has more details about what each of the arguments are and how they're used, though note that you should ensure you understand the underlying SQL concept of CTE queries before using this API.

### Mapping

Creates a map based on the first two columns of the query result.
Expand Down
61 changes: 60 additions & 1 deletion en/04_Changelogs/5.2.0.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,13 +7,72 @@ title: 5.2.0 (unreleased)
## Overview

- [Features and enhancements](#features-and-enhancements)
- [New ORM features](#new-orm-features)
- [ErrorPage allowed codes configuration](#errorpage-allowed-codes-configuration)
- [Other new features](#other-new-features)
- [API changes](#api-changes)
- [Bug fixes](#bug-fixes)

## Features and enhancements

### New ORM features {#new-orm-features}

This release comes jampacked with new ORM features, granting you access to some new abstractions for more powerful and efficient queries.

#### UNION clause {#orm-union-clause}

Abstractions for the SQL `UNION` clause have been added to `SQLSelect` and `DataQuery`.

To add a `UNION` clause to an `SQLSelect`, call the [`SQLSelect::addUnion()`](api:SilverStripe\ORM\Queries\SQLSelect::addUnion()) method and pass in the `SQLSelect` query you want to combine using a union.

For the second argument, you can leave it blank for a default union (which is functionality equivalent to a distinct union in MySQL) - or you can pass in one of the `SQLSelect::UNION_ALL` or `SQLSelect::UNION_DISTINCT` constants for a `UNION ALL` or `UNION DISTINCT` clause respectively.

```php
$baseQuery = SQLSelect::create()->setFrom($tableName)->addWhere(...);
$anotherQuery = SQLSelect::create()->setFrom($tableName)->addWhere(...);
$baseQuery->addUnion($anotherQuery, SQLSelect::UNION_DISTINCT);
```

To add a `UNION` clause to an `DataQuery`, call the [`DataQuery::union()`](api:SilverStripe\ORM\DataQuery::union()) method and pass in either another `DataQuery` or an `SQLSelect` query you want to combine using a union. The same constants used for `SQLSelect` can be passed in here as well.

```php
$baseQuery = DataQuery::create(MyClass::class)->where(...);
$anotherQuery = DataQuery::create(MyClass::class)->where(...);
$baseQuery->union($anotherQuery, SQLSelect::UNION_ALL);
```

#### Common Table Expressions (CTEs aka the WITH clause) {#orm-with-clause}

Abstractions for Common Table Expressions (aka the SQL `WITH` clause) have been added to `SQLSelect` and `DataQuery`.

Common Table Expressions are a powerful tool both for optimising complex queries, and for creating recursive queries. This functionality is abstracted in the [`SQLSelect::addWith()`](api:SilverStripe\ORM\Queries\SQLSelect::addWith()) and [`DataQuery::with()`](api:SilverStripe\ORM\DataQuery::with()) methods.

Older database servers don't support this functionality, and the core implementation is only valid for MySQL, so if you are using this functionality in an open source module or a project that you can't guarantee the type and version of database being used, you should wrap the query in a condition checking if CTEs are supported. You can do that by calling [`DB::get_conn()->supportsCteQueries()`](api:SilverStripe\ORM\Connect\Database::supportsCteQueries()).

Check out the [SQL Queries](/developer_guides/model/sql_select/#cte) and [Data Model and ORM](/developer_guides/model/data_model_and_orm/#cte) documentation for usage details and examples.

#### RIGHT JOIN clause {#orm-right-join}

Abstractions for `RIGHT JOIN` have been added with the new [`DataList::rightJoin()`](api:SilverStripe\ORM\DataList::rightJoin()), [`DataQuery::rightJoin()`](api:SilverStripe\ORM\DataQuery::rightJoin()), and [`SQLConditionalExpression::addRightJoin()`](api:SilverStripe\ORM\Queries\SQLConditionalExpression::addRightJoin()) methods. The signature for these methods is identical to their `LEFT JOIN` and `INNER JOIN` counterparts.

#### Support for multiple (or no) tables in the FROM clause {#orm-from-clause}

Previously the `SQLConditionalExpression` abstraction couldn't handle multiple table names being passed into its `FROM` clause. This restriction has been removed, so you can now have queries selecting from multiple tables so long as your database supports it. If you were working around that limitation by adding an explicit comma to subsequent tables in the `FROM` clause for your queries, you'll need to remove the comma.

You can also now choose to _not_ have a `FROM` clause in an `SQLSelect` query, which can be useful for setting up simple queries to be used in unit tests.

#### Better support for custom column selections in `DataQuery` {#orm-custom-columns}

When using `DataQuery`, it is possible to use collations and other raw SQL field statements as part of the query's `SELECT` clause. If these have an alias that matches the name of an existing database column, this results in an exception being thrown.

You can choose to allow those conflicts to be resolved via a [`CASE`](https://dev.mysql.com/doc/refman/en/case.html) statement. In that scenario, if the value in the database column is null, the value for your custom field statement will be used. This is enabled per query by passing `true` to the new [`DataQuery::setAllowCollidingFieldStatements()`](api:SilverStripe\ORM\DataQuery::setAllowCollidingFieldStatements()) method.

```php
$query = new DataQuery(MyClass::class);
$query->selectField('"my custom title" AS "Title"');
$query->setAllowCollidingFieldStatements(true);
```

### ErrorPage allowed codes configuration

By default, all available error codes are present in the dropdown in the CMS. This can be overwhelming and there are a few (looking at you, 418) that can
Expand All @@ -32,7 +91,7 @@ SilverStripe\ErrorPage\ErrorPage:
## API changes
### silverstripe/framework
### silverstripe/framework {#api-silverstripe-framework}
The following legacy subclasses of [`PasswordEncryptor`](api:SilverStripe\Security\PasswordEncryptor) have been deprecated, and will be removed in a future major release. If you are using one of these password encryptors in your projects, we strongly recommend swapping to one that has not been deprecated ([`PasswordEncryptor_Blowfish`](api:SilverStripe\Security\PasswordEncryptor_Blowfish) is the current recommendation, and is the default encryptor for passwords in new installations). Note that changing the password encryptor will also require that all of your members reset their passwords.

Expand Down

0 comments on commit c6525f2

Please sign in to comment.