do a much better job of explaining query language concepts

and add an example of a union query
This commit is contained in:
Gavin 2022-01-03 15:57:50 +01:00 committed by Gavin King
parent cf4d2d4338
commit 49d9155f4e
2 changed files with 223 additions and 85 deletions

View File

@ -69,14 +69,14 @@ Most of the complexity here arises from the interplay of set operators (`union`,
We'll describe the various clauses of a query later in this chapter, but to summarize, a query might have:
* a `select` list, specifying a projection (the things to return from the query),
* a `from` clause and joins, specifying the entities involved in the query,
* a `where` clause, specifying a restriction,
* a `group by` clause, for aggregation,
* a `having` clause, specifying a restriction to apply _after_ aggregation,
* set operators applied to the results of multiple subqueries,
* an `order by` clause, for ordering the results, and even
* a `limit`/`offset` clause, for limiting the results.
* a `select` list, specifying a <<hql-select-clause,projection>> (the things to return from the query),
* a `from` clause and joins, <<hql-from-clause,specifying>> the entities involved in the query,
* a `where` clause, specifying a <<hql-where-clause,restriction>>,
* a `group by` clause, for <<hql-group-by,aggregation>>,
* a `having` clause, specifying a <<hql-having,restriction>> to apply _after_ aggregation,
* <<hql-set-operators,set operators>> applied to the results of multiple subqueries,
* an `order by` clause, for <<hql-order-by,sorting>> the results, and even
* a `limit`/`offset` clause, for <<hql-limit-offset,limiting or paginating>> the results.
Every one of these clauses is optional!
@ -526,7 +526,7 @@ Additional datetime operations, including the useful `format()` function, are de
Identification variables, and path expressions beginning with an identification variable are legal expression in almost every context.
See <<hql-from-clause>>.
See <<hql-identification-variables>> and <<hql-implicit-join>>.
[[hql-case-expressions]]
==== Case expressions
@ -1142,7 +1142,7 @@ This less-than-lovely fragment of the HQL ANTLR grammar tells is that the thing
* a list of values enclosed in parentheses,
* a query parameter,
* a subquery, or
* one the the functions `elements()` or `indices()` defined <<hql-elements-indices,above>>.
* one of the functions `elements()` or `indices()` defined <<hql-elements-indices,above>>.
The type of the expression on the left, and the types of all the values on the right must be compatible.
@ -1269,14 +1269,15 @@ include::{sourcedir}/HQLTest.java[tags=hql-member-of-collection-predicate-exampl
[[hql-logical-operators]]
==== Logical operators
The logical operators are `and`, `or`, and `not`.
The logical operators are binary infix `and` and `or`, and unary prefix `not`.
Just like SQL, logical expressions are based on ternary logic.
A logical operator evaluates to null if it has a null operand.
[[hql-from-clause]]
=== The `from` clause
=== Declaring root entities: `from`
The `from` clause is responsible for defining the entities available in the rest of the query, and assigning them aliases, or, in the language of the JPQL specification, _identification variables_.
The `from` clause is responsible for declaring the entities available in the rest of the query, and assigning them aliases, or, in the language of the JPQL specification, _identification variables_.
[[hql-identification-variables]]
==== Identification variables
@ -1382,9 +1383,13 @@ This behavior may be slightly adjusted using the `@Polymorphism` annotation.
See <<chapters/domain/inheritance.adoc#entity-inheritance-polymorphism>> for more.
[[hql-join]]
=== Joins
=== Declaring joined entities
Joins allow us to navigate from one entity to another, via its associations, or via explicit join conditions.
There are:
- _explicit joins_, declared within the `from` clause using the keyword ``join``,
- and _implicit joins_, which don't need to be declared in the `from` clause.
[[hql-explicit-join]]
==== Explicit joins
@ -1467,7 +1472,11 @@ include::{sourcedir}/HQLTest.java[tags=hql-explicit-join-jpql-on-example]
[[hql-explicit-fetch-join]]
==== `fetch join` for association fetching
A ``fetch join`` overrides the laziness of a given association, specifying that the association should be fetched with a SQL join.
A `fetch join` overrides the laziness of a given association, specifying that the association should be fetched with a SQL join.
The join may be an inner or outer join.
* A `join fetch`, or, more explicitly, `inner join fetch`, only returns base entities with an associated entity.
* A `left join fetch`, or&mdash;for lovers of verbosity&mdash;``left outer join fetch``, returns all the base entities, including those which have no associated joined entity.
[IMPORTANT]
====
@ -1476,11 +1485,6 @@ To achieve acceptable performance with HQL, you'll need to use `fetch join` quit
Without it, you'll quickly run into the dreaded "n+1 selects" problem.
====
[NOTE]
====
Fetch joins are disallowed in subqueries.
====
For example, if `Person` has a one-to-many association named `phones`, the use of `join fetch` in the following query specifies that the collection elements should be fetched in the same SQL query:
[[hql-explicit-fetch-join-example]]
@ -1494,19 +1498,28 @@ include::{sourcedir}/HQLTest.java[tags=hql-explicit-fetch-join-example]
In this example, we used a left outer join because we also wanted to obtain customers with no orders.
* A `join fetch`, or, more explicitly, `inner join fetch`, only returns base entities with an associated entity.
* A `left join fetch`, or&mdash;for lovers of verbosity&mdash;``left outer join fetch``, returns all the base entities, including those which have no associated joined entity.
A query may have more than one `fetch join`, but be aware that:
It's usually a bad idea to apply any restriction to a ``fetch join``ed entity, since then the elements of the fetched collection will be incomplete.
Therefore, avoid assigning an identification variable to fetched joins except for the purpose of specifying nested fetch joins.
* it's perfectly safe to fetch several to-one associations in series or parallel in a single query, and
* a single series of _nested_ fetch joins is also fine, but
* fetching multiple collections or to-many associations in _parallel_ results in a Cartesian product at the database level, and might exhibit very poor performance.
HQL doesn't disallow it, but it's usually a bad idea to apply a restriction to a ``fetch join``ed entity, since the elements of the fetched collection would be incomplete.
Indeed, it's best to avoid even assigning an identification variable to a fetched joined entity except for the purpose of specifying a nested fetch join.
[IMPORTANT]
====
Fetch joins should not be used in paged queries (`setFirstResult()` or `setMaxResults()`).
Fetch joins should not be used in limited or paged queries.
This includes:
Nor should they be used with the `scroll()` or `stream()` methods.
- queries executed using `setFirstResult()` or `setMaxResults()`, as in <<jpql-pagination>>, or
- queries with a limit or offset declared in HQL, described below in <<hql-limit-offset>>.
Nor should they be used with the `scroll()` and `stream()` methods described in <<hql-api-incremental>>.
====
Fetch joins are disallowed in subqueries, where they would make no sense.
[[hql-join-treat]]
==== Joins with typecasts
@ -1630,12 +1643,42 @@ include::{sourcedir}/HQLTest.java[tags=hql-collection-index-operator-example]
See <<hql-more-functions>> for additional collection-related functions.
[[hql-select-clause]]
=== The `select` clause
=== Projection: `select`
The `select` list identifies which objects and values to return as the query results.
If there are multiple expressions in the select list, then, by default, each query result is packaged as an array of type `Object[]`.
Simplifying slightly, the BNF for a select item is:
NOTE: This operation is called _projection_.
Any of the expression types discussed in <<hql-expressions>> may occur in the projection list, unless otherwise noted.
There might be multiple items in a projection list, in which case each query result is a tuple, and this poses a problem:
Java doesn't have a good way to represent tuples.
If there's just one projected item in the `select` list, then, no sweat, that's the type of each query result.
There's no need to bother with trying to represent a "tuple of length 1".
But if there are multiple expressions in the select list then:
- by default, each query result is packaged as an array of type `Object[]`, or
- if explicitly requested by passing the class `Tuple` to `createQuery()`, the query result is packaged as an instance of `javax.persistence.Tuple`.
[[hql-select-clause-projection-example]]
//.Query results as lists
====
[source, JAVA, indent=0]
----
include::{sourcedir}/HQLTest.java[tags=jpql-projection-example]
----
====
The names of the `Tuple` elements are determined by the aliases given to the projected items in the select list.
If no aliases are specified, the elements may be accessed by their position in the list (positions are numbered from 0).
Unfortunately, neither `Object[]` nor `Tuple` lets us access an individual item in a result tuple of an HQL query without explicitly specifying the type of the item.
(Using a typecast in the case of `Object[]`, or by passing the class object to `get()` in the case of `Tuple`.)
But there's another option, as we're about to see.
Simplifying slightly, the BNF for a projected item is:
[[hql-select-item-bnf]]
====
@ -1645,11 +1688,9 @@ include::{extrasdir}/select_item_bnf.txt[]
----
====
where `instantiatiationArgs` is essentially a nested select list.
where `instantiatiationArgs` is essentially a nested projection list.
Any of the expression types discussed in <<hql-expressions>> may occur in the select list, unless otherwise noted.
But there's one particular expression type that's only legal in the select clause: the `instantiation` rule in the BNF above.
So there's a special expression type that's only legal in the select clause: the `instantiation` rule in the BNF above.
Let's see what it does.
[[hql-select-new]]
@ -1668,26 +1709,16 @@ include::{sourcedir}/HQLTest.java[tags=hql-select-clause-dynamic-instantiation-e
----
====
The class must be specified by its fully qualified name in the query, and it must have a matching constructor.
The class must be specified by its fully qualified name, and it must have a matching constructor.
[IMPORTANT]
====
This class does not need to be mapped or annotated in any way.
Even if the class _is_ an entity class, the resulting instances are _not_ managed entities associated with the session.
Even if the class _is_ an entity class, the resulting instances are _not_ managed entities and are _not_ associated with the session.
====
Alternatively, the query may specify that each result should be packaged as a list or map instead of as an array.
Then the query results are returned as a `List<List<Object>>` or `List<Map<String,Object>>` instead of as a `List<Object[]>`.
[[hql-select-clause-dynamic-list-instantiation-example]]
//.Query results as lists
====
[source, JAVA, indent=0]
----
include::{sourcedir}/HQLTest.java[tags=hql-select-clause-dynamic-list-instantiation-example]
----
====
Alternatively, using the syntax `select new map`, the query may specify that each result should be packaged as a map:
[[hql-select-clause-dynamic-map-instantiation-example]]
//.Query results as maps
@ -1698,8 +1729,26 @@ include::{sourcedir}/HQLTest.java[tags=hql-select-clause-dynamic-map-instantiati
----
====
In the case of a map, the keys of the map are defined by the aliases given to the select expressions.
If no aliases are specified, the keys will be column indexes: 0, 1, 2, etc.
The keys of the map are determined by the aliases given to the projected items in the select list.
If no aliases are specified, the key of an item is its position in the list (positions are numbered from 0).
Or, using the syntax `select new list`, the query may specify that each result should be packaged as a list:
[[hql-select-clause-dynamic-list-instantiation-example]]
//.Query results as lists
====
[source, JAVA, indent=0]
----
include::{sourcedir}/HQLTest.java[tags=hql-select-clause-dynamic-list-instantiation-example]
----
====
[NOTE]
====
This is an older syntax, that predates JPQL.
In hindsight, it's hard to see what advantage `List<Object>` offers compared to `Object[]`.
On the other hand, `Map` is a perfectly fine alternative `Tuple`, but isn't portable to other persistence providers.
====
[[hql-distinct]]
==== `distinct`
@ -1718,8 +1767,8 @@ include::{sourcedir}/SelectDistinctTest.java[tags=hql-distinct-projection-query-
[NOTE]
====
As of Hibernate 6, duplicate results arising from the use of `join fetch` are automatically removed by Hibernate in memory _after_ reading the database results and materializing entity instances as Java objects.
It's no longer necessary to remove duplicate results explicitly, and `distinct` should not be used in this case.
As of Hibernate 6, duplicate results arising from the use of `join fetch` are automatically removed by Hibernate in memory, _after_ reading the database results and materializing entity instances as Java objects.
It's no longer necessary to remove duplicate results explicitly, and, in particular, `distinct` should not be used for this purpose.
====
[[hql-aggregate-functions]]
@ -1768,12 +1817,12 @@ HQL defines the two additional aggregate functions which accept a logical predic
| `every()` | Logical predicate | `Boolean`
|===
Aggregate functions often appear in queries with a `group by` clause, as described <<hql-group-by,below>>.
NOTE: Aggregate functions usually appear in the `select` clause, but control over aggregation is the responsibility of the `group by` clause, as described <<hql-group-by,below>>.
[[hql-aggregate-functions-filter]]
==== `filter`
All aggregate functions support the inclusion of a _filter clause_, a sort of mini-`where`-clause applying to just one item of the select list:
All aggregate functions support the inclusion of a _filter clause_, a sort of mini-`where`-clause applying a restriction to just one item of the select list:
[[hql-aggregate-functions-filter-example]]
//.Using filter with aggregate functions
@ -1790,19 +1839,34 @@ include::{sourcedir}/HQLTest.java[tags=hql-aggregate-functions-filter-example]
====
[[hql-where-clause]]
=== The `where` clause
=== Restriction: `where`
The `where` clause restricts the results returned from a select query or limits the scope of update and delete queries.
The `where` clause restricts the results returned by a `select` query or limits the scope of an `update` or `delete` query.
It contains a logical expression.
NOTE: This operation is usually called _selection_, but since that term is often confused with the `select` keyword, and since both projection and selection involve "selecting" things, here we'll use the less-ambiguous term _restriction_.
A restriction is nothing more than a single logical expression, a topic we exhausted above in <<hql-conditional-expressions>>.
[[hql-aggregation]]
=== Aggregation: `group by` and `having`
An aggregate query is one with <<hql-aggregate-functions,aggregate functions>> in its projection list.
The `group by` clause divides the result set into groups, so that a query with aggregate functions in the select list returns not a single result for the whole query, but one result for each group.
NOTE: In short, _grouping_ controls the effect of _aggregation_.
A query with aggregation may also have a `having` clause, a restriction applied to the groups.
[[hql-group-by]]
=== The `group by` clause
==== `group by`
The `group by` clause divides the result set into groups, so that a query with aggregate functions in the select list returns not a single result, but one result for each group.
The result set is grouped by the values of expressions that occur in the `group by` clause.
The `group by` clause looks quite similar to the `select` clause&mdash;it has a list of grouped items, but:
As an example, consider the following queries:
- if there's just one item, then the query will have a single result for each unique value of that item, or
- if there are multiple items, the query will have a result for each unique _combination_ or their values.
Consider the following queries:
[[hql-group-by-example]]
//.Group by example
@ -1813,8 +1877,8 @@ include::{sourcedir}/HQLTest.java[tags=hql-group-by-example]
----
====
The first query retrieves the complete total of all orders.
The second retrieves the total for each customer, grouped after grouping the orders by customer.
The first query retrieves the complete total over all orders.
The second retrieves the total for each customer, after grouping the orders by customer.
[[hql-group-by-rollup-cube]]
==== `rollup` and `cube`
@ -1828,9 +1892,9 @@ These functions are especially useful for reporting:
* A `group by` clause with `cube()` allows totals for every combination of columns.
[[hql-having]]
=== The `having` clause
==== `having`
In a grouped query, the `where` clause applies to the non-aggregated values (essentially it determines whether rows will make it into the aggregation).
In a grouped query, the `where` clause applies to the non-aggregated values (it determines which rows will make it into the aggregation).
The `having` clause also restricts results, but it operates on the aggregated values.
In an <<hql-group-by-example,example above>>, we retrieved `Call` duration totals for all persons.
@ -1849,9 +1913,9 @@ The `having` clause follows the same rules as the `where` clause and is also mad
`having` is applied after the groupings and aggregations have been done, while the `where` clause is applied before.
[[hql-set-operators]]
=== `union`, `intersect`, and `except`
=== Operations on result sets: `union`, `intersect`, and `except`
Query results may be combined using the operators:
These operators apply not to expressions, but to entire result sets:
- `union` and `union all`,
- `intersect` and `intersect all`, and
@ -1859,25 +1923,48 @@ Query results may be combined using the operators:
Just like in SQL, `all` suppresses the elimination of duplicate results.
[[hql-union-example]]
====
[source, JAVA, indent=0]
----
include::{sourcedir}/HQLTest.java[tags=hql-union-example]
----
====
[[hql-order-by]]
=== The `order by` clause
=== Sorting: `order by`
By default, the results of the query are returned in an arbitrary order.
The `order by` clause specifies a list of selected items used to order the results.
Each item may be:
* an attribute of an entity or embeddable class,
* a scalar expression involving arithmetic operators, function application, etc,
* an alias declared in the select list, or
* a literal integer indicating the ordinal position of an item in the select list.
[NOTE]
====
The JPQL specification requires that every expression in the `order by` clause must also occur in the `select` clause.
HQL does not enforce this restriction, but applications desiring database portability should be aware that some databases _do_.
Imposing an order on a set is called _sorting_.
A relation (a database table) is a set, and therefore certain particularly dogmatic purists have argued that sorting has no place in the algebra of relations.
We think this is more than a bit silly: practical data analysis almost always involves sorting, which is a perfectly well-defined operation.
====
The BNF for an `order by` item is:
The `order by` clause specifies a list of projected items used to sort the results.
Each sorted item may be:
* an attribute of an entity or embeddable class,
* a more complex <<hql-expressions,expression>>,
* the alias of a projected item declared in the select list, or
* a literal integer indicating the ordinal position of a projected item in the select list.
Of course, in principle, only certain types may be sorted: numeric types, string, and date and time types.
But HQL is very permissive here and will allow an expression of almost any type to occur in a sort list.
Even the identification variable of an entity with a sortable identifier type may occur as a sorted item.
[NOTE]
====
The JPQL specification requires that every sorted item in the `order by` clause also occur in the `select` clause.
HQL does not enforce this restriction, but applications desiring database portability should be aware that some databases _do_.
Therefore, you might wish to avoid the use of complex expressions in the sort list.
====
The BNF for a sorted item is:
[[hql-order-by-item-bnf]]
====
@ -1887,15 +1974,15 @@ include::{extrasdir}/order_by_item_bnf.txt[]
----
====
Each item listed in the `order by` clause may explicitly specify a direction, either:
Each sorted item listed in the `order by` clause may explicitly specify a direction, either:
* `asc` for ascending order, or
* `desc` for descending order.
If no direction is explicitly specified, the results are returned in ascending order.
Of course, there is an ambiguity with respect to null values.
Therefore, the order of null values may also be explicitly specified:
Of course, there's an ambiguity with respect to null values.
Therefore, the sorting of null values may also be explicitly specified:
* `nulls first` puts null values at the beginning of the result set, and
* `nulls last` puts them last.
@ -1910,7 +1997,16 @@ include::{sourcedir}/HQLTest.java[tags=hql-order-by-example]
====
[[hql-limit-offset]]
=== The `limit` and `offset` clauses
=== Limits and offsets
It's often useful to place a hard upper limit on the number of results that may be returned by a query.
[NOTE]
====
_Limiting_ certainly _isn't_ a well-defined relational operation, and must be used with care.
A limit can easily break the semantics of certain other features of HQL, including <<hql-explicit-fetch-join,fetch joins>>.
====
The `limit` and `offset` clauses are an alternative to the use of `setMaxResults()` and `setFirstResult()` respectively.

View File

@ -18,6 +18,7 @@ import java.util.stream.Collectors;
import java.util.stream.Stream;
import jakarta.persistence.FlushModeType;
import jakarta.persistence.Query;
import jakarta.persistence.Tuple;
import jakarta.persistence.TypedQuery;
import org.hibernate.CacheMode;
@ -67,7 +68,7 @@ public class HQLTest extends BaseEntityManagerFunctionalTestCase {
protected Class<?>[] getAnnotatedClasses() {
return new Class<?>[] {
Person.class,
Phone.class,
Phone.class,
Call.class,
Account.class,
CreditCardPayment.class,
@ -154,8 +155,8 @@ public class HQLTest extends BaseEntityManagerFunctionalTestCase {
@Test
public void test_hql_select_simplest_example() {
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
List<Object> objects = session.createQuery(
"from java.lang.Object",
Object.class )
@ -648,6 +649,47 @@ public class HQLTest extends BaseEntityManagerFunctionalTestCase {
});
}
@Test
public void test_projection_example() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::jpql-projection-example[]
List<Object[]> results = entityManager.createQuery(
"select p.name, p.nickName " +
"from Person p ",
Object[].class
).getResultList();
for (Object[] result : results) {
String name = (String) result[0];
String nickName = (String) result[1];
}
List<Tuple> tuples = entityManager.createQuery(
"select p.name as name, p.nickName as nickName " +
"from Person p ",
Tuple.class
).getResultList();
for (Tuple tuple : tuples) {
String name = tuple.get("name", String.class);
String nickName = tuple.get("nickName", String.class);
}
//end::jpql-projection-example[]
});
}
@Test
public void test_union_example() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::hql-union-example[]
List<String> results = entityManager.createQuery(
"select p.name from Person p " +
"union " +
"select p.nickName from Person p where p.nickName is not null",
String.class
).getResultList();
//end::hql-union-example[]
assertEquals( 4, results.size() );
});
}
@Test
public void test_jpql_api_example() {
doInJPA( this::entityManagerFactory, entityManager -> {
@ -1361,7 +1403,7 @@ public class HQLTest extends BaseEntityManagerFunctionalTestCase {
//tag::hql-aggregate-functions-simple-filter-example[]
List<Long> callCount = entityManager.createQuery(
"select count(c) filter(where c.duration < 30) " +
"select count(c) filter (where c.duration < 30) " +
"from Call c ",
Long.class )
.getResultList();
@ -1376,7 +1418,7 @@ public class HQLTest extends BaseEntityManagerFunctionalTestCase {
//tag::hql-aggregate-functions-filter-example[]
List<Object[]> callCount = entityManager.createQuery(
"select p.number, count(c) filter(where c.duration < 30) " +
"select p.number, count(c) filter (where c.duration < 30) " +
"from Call c " +
"join c.phone p " +
"group by p.number",