diff --git a/documentation/documentation.gradle b/documentation/documentation.gradle index 14f60b95f5..a2d397f96c 100644 --- a/documentation/documentation.gradle +++ b/documentation/documentation.gradle @@ -194,6 +194,8 @@ tasks.register('renderIntroduction', AsciidoctorTask) {task-> } } +// HQL Guide ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ + tasks.register('renderQLPdf', AsciidoctorPdfTask) {task-> group = "Documentation" description = 'Renders the Query Language document in PDF format using Asciidoctor.' diff --git a/documentation/src/main/asciidoc/querylanguage/Concepts.adoc b/documentation/src/main/asciidoc/querylanguage/Concepts.adoc new file mode 100644 index 0000000000..a5618df204 --- /dev/null +++ b/documentation/src/main/asciidoc/querylanguage/Concepts.adoc @@ -0,0 +1,488 @@ +[[basic-concepts]] +== Basic concepts + +This document describes Hibernate Query Language (HQL), which is, in some sense, a dialect of the Java (now Jakarta) Persistence Query Language (JPQL). + +Or is it the other way around? + +[NOTE] +==== +JPQL was inspired by early versions of HQL, and is a subset of modern HQL. +Here we focus on describing the complete, more powerful HQL language as it exists today. + +If strict JPA compliance is what you're looking for, use the setting `hibernate.jpa.compliance.query=true`. +With this configuration, any attempt to use HQL features beyond the JPQL subset will result in an exception. + +We don't recommend the use of this setting. +==== + +The truth is that HQL today has capabilities that go far beyond what is possible in plain JPQL. +We're not going to fuss too much about not limiting ourselves to the standard here. +Faced with a choice between writing database-specific native SQL, or database-independent HQL, we know what our preference is. + +[[and-sqk]] +=== HQL and SQL + +Throughout this document, we'll assume you know SQL and the relational model, at least at a basic level. +HQL and JPQL are loosely based on SQL and are easy to learn for anyone familiar with SQL. + +For example, if you understand this SQL query: + +[source,sql] +---- +select book.title, pub.name +from Book as book + join Publisher as pub + on book.publisherId = pub.id +where book.title like 'Hibernate%' +order by book.title +---- + +Then we bet you can already make sense of this HQL: + +[source,sql] +---- +select book.title, pub.name +from Book as book + join book.publisher as pub +where book.title like 'Hibernate%' +order by book.title +---- + +You might notice that even for this very simple example, the HQL version is slightly shorter. +This is typical. +Actually, HQL queries are usually much more compact than the SQL they compile to. + +In this chapter, we'll demonstrate how similar HQL is to SQL by giving a quick overview of the basic statement types. +You'll be bored to discover they're exactly the ones you expect: `select`, `insert`, `update`, and `delete`. + +[WARNING] +==== +This is a reference guide. +We're not going to explain basic concepts like ternary logic, joins, aggregation, selection, or projection, because that information is freely available elsewhere, and anyway we couldn't possibly do these topics justice here. +If you don't have a firm grasp of these ideas, it's time to pick up a book about SQL or about the relational model. +==== + +But first we need to mention something that's a bit different to SQL. +HQL has a slightly complicated way of dealing with case sensitively. + +[[case-sensitivity]] +=== Identifiers and case sensitivity + +An identifier is a name used to refer to an entity, an attribute of a Java class, an <>, or a function. + +For example, `Book`, `title`, `author`, and `upper` are all identifiers, but they refer to different kinds of things. +In HQL and JPQL, the case sensitivity of an identifier depends on the kind of thing the identifier refers to. + +The rules for case sensitivity are: + +- keywords and function names are case-insensitive, but +- identification variable names, Java class names, and the names of attributes of Java classes, are case-sensitive. + +We apologize for this inconsistency. +In hindsight, it might have been better to define the whole language as case-sensitive. + +[%unbreakable] +[NOTE] +==== +Incidentally, it's standard practice to use lowercase keywords in HQL and JPQL. + +The use of uppercase keywords indicates an endearing but unhealthy attachment to the culture of the 1970's. +==== + +Just to reiterate these rules: + +[cols="45,~"] +|=== +| `select`, `SeLeCT`, `sELEct`, and `SELECT` | All the same, `select` is a keyword +| `upper(name)` and `UPPER(name)` | Same, `upper` is a function name +| `from BackPack` and `from Backpack` | Different, refer to different Java classes +| `person.nickName` and `person.nickname` | Different, since the path expression element `nickName` refers to an attribute of an entity defined in Java +| `person.nickName`, `Person.nickName`, and `PERSON.nickName` | All different, since the first element of a path expression is an <> +|=== + +[CAUTION] +==== +The JPQL specification defines identification variables as case-_insensitive_. + +And so in strict JPA-compliant mode, Hibernate treats `person.nickName`, `Person.nickName`, and `PERSON.nickName` as the _same_. +==== + +A _quoted identifier_ is written in backticks. Quoting lets you use a keyword as an identifier, for example `` thing.\`select` ``. + +[[type-system]] +=== Type system + +JPA doesn't have a well-specified type system, but, reading between the lines a bit, the following types may be discerned: + +- entity types, +- numeric values, +- strings, +- dates/times, +- booleans, and +- enumerated types. + +Such a coarse-grained type system is in some sense an insufficient constraint on implementors of the specification, or, viewed from a different perspective, it leaves us quite a lot of flexibility. + +The way HQL interprets this type system is to assign a Java type to every expression in the language. +Thus, numeric expressions have types like `Long`, `Float`, or `BigInteger`, date/time expressions have types like `LocalDate`, `LocalDateTime`, or `Instant`, and boolean expressions are always of type `Boolean`. + +Going further, an expression like `local datetime - document.created` is assigned the Java type `java.time.Duration`, a type which doesn't appear anywhere in the JPA specification. + +Since the language must be executed on SQL databases, every type accommodates null values. + +[[null-values-and-ternary-logic]] +==== Null values and ternary logic + +The SQL `null` behaves quite differently to a null value in Java. +In Java, an expression like `number + 1` produces in an exception if `number` is null. +But in SQL, and therefore also in HQL and JPQL, such an expression evaluates to `null`. + +[IMPORTANT] +==== +It's almost always the case that an operation applied to a null value yields another null value. +This applies to function application, to operators like `*` and `||`, to comparison operators like `<` and `=`, and even to logical operations like `and` and `not`. + +The exceptions to this rule are the functions `coalesce()` and `ifnull()` which are specifically designed for <>. +==== + +This rule is the source of the famous (and controversial) _ternary logic_ of SQL. +A logical expression like `firstName='Gavin' and team='Hibernate'` isn't restricted to the values `true` and `false`. +It may also be `null`. + +This can in principle lead to some quite unintuitive results: we can't use the law of the excluded middle to reason about logical expressions in SQL! +But in practice, we've once never run into a case where this caused us problems. + +As you probably know, when a logical predicate occurs as a <>, rows for which the predicate evaluates to `null` are _excluded_ from the result set. +That is, in this context at least, a logical null is interpreted as "effectively false". + +[[statement-types]] +=== Statement types + +HQL features four different kinds of statement: + +- `select` queries, +- `update` statements, +- `delete` statements, and +- `insert ... values` and `insert ... select` statements. + +Collectively, `insert`, `update`, and `delete` statements are sometimes called _mutation queries_. +We need to be a little bit careful when executing mutation queries via a stateful session. + +[IMPORTANT] +==== +The effect of an `update` or `delete` statement is not reflected in the persistence context, nor in the state of entity objects held in memory at the time the statement is executed. + +It's the responsibility of the client program to maintain synchronization of state held in memory with the database after execution of an `update` or `delete` statement. +==== + +Let's consider each type of mutation query in turn, beginning with the most useful type. + +[[update]] +==== Update statements + +The https://en.wikipedia.org/wiki/Backus%E2%80%93Naur_Form[BNF] for an `update` statement is quite straightforward: + +[[update-bnf-example]] +[source, antlrv4] +---- +include::{extrasdir}/statement_update_bnf.txt[] +---- + +The `set` clause has a list of assignments to attributes of the given entity. + +For example: + +[[update-example]] +[source, hql] +---- +update Person set nickName = 'Nacho' where name = 'Ignacio' +---- + +Update statements are polymorphic, and affect mapped subclasses of the given entity class. +Therefore, a single HQL `update` statement might result in multiple SQL update statements executed against the database. + +An `update` statement must be executed using `Query.executeUpdate()`. + +[[update-examples]] +[source, java] +---- +// JPA API +int updatedEntities = entityManager.createQuery( + "update Person p set p.name = :newName where p.name = :oldName") + .setParameter("oldName", oldName) + .setParameter("newName", newName) + .executeUpdate(); +---- +[source, java] +---- +// Hibernate native API +int updatedEntities = session.createMutationQuery( + "update Person set name = :newName where name = :oldName") + .setParameter("oldName", oldName) + .setParameter("newName", newName) + .executeUpdate(); +---- + +The integer value returned by `executeUpdate()` indicates the number of entity instances affected by the operation. + +[NOTE] +==== +In a `JOINED` inheritance hierarchy, multiple rows are required to store a single entity instance. +In this case, the update count returned by Hibernate might not be exactly the same as the number of rows affected in the database. +==== + +An `update` statement, by default, does not affect the column mapped by the `@Version` attribute of the affected entities. + +Adding the keyword `versioned`β€”writing `update versioned`β€”specifies that Hibernate should increment the version number or update the last modification timestamp. + +// [NOTE] +// ==== +// `update versioned` does not work with custom version types defined by implementing `UserVersionType`, and is not available in JPQL. +// ==== + +[[update-versioned-example]] +[source, hql] +---- +update versioned Book set title = :newTitle where ssn = :ssn +---- + +Unfortunately, an `update` statement may not directly join other entities, not even using an <>, but it may have subqueries in its `set` clause, or in the `where` clause, which may contain joins. + +[[delete]] +==== Delete statements + +The BNF for a `delete` statement is even simpler: + +[[delete-bnf-example]] +[source, antlrv4] +---- +include::{extrasdir}/statement_delete_bnf.txt[] +---- + +For example: + +[source,hql] +---- +delete Author author where is empty author.books +---- + +As in SQL, the presence or absence of the `from` keyword has absolutely no effect on the semantics of the `update` statement. + +Just like update statements, delete statements are polymorphic, and affect mapped subclasses of the given entity class. +Therefore, a single HQL `delete` statement might result in multiple SQL delete statements executed against the database. + +A `delete` statement is executed by calling `Query.executeUpdate()`. + +The integer value returned by `executeUpdate()` indicates the number of entity instances affected by the operation. + +A `delete` statement may not directly join other entities, but it may have subqueries in the `where` clause, which may contain joins. + +[[insert]] +==== Insert statements + +There are two kinds of `insert` statement: + +- `insert ... values`, where the attribute values to insert are given directly as tuples, and +- `insert ... select`, where the inserted attribute values are sourced from a subquery. + +The first form inserts a single row in the database, or multiple rows if you provide multiple tuples in the `values` clause. +The second form may insert many new rows, or none at all. + +[%unbreakable] +[TIP] +==== +The first sort of `insert` statement is not as useful. +It's usually better to just use `persist()`. + +On the other hand, you might consider using it to set up test data. +==== + +[NOTE] +==== +`insert` statements are not part of JPQL. +==== + +The BNF for an `insert` statement is: + +[[insert-bnf-example]] +[source, antlrv4] +---- +include::{extrasdir}/statement_insert_bnf.txt[] +---- + +For example: + +[[insert-example]] +[source, hql] +---- +insert Person (id, name) + values (100L, 'Jane Doe'), (200L, 'John Roe') +---- + +[source, hql] +---- +insert into Author (id, name, bio) + select id, name, name || ' is a newcomer for ' || str(year(local date)) + from Person + where id = :pid +---- + +As in SQL, the presence or absence of the `into` keyword has no effect on the semantics of the `insert` statement. + +From these examples we might notice that `insert` statements are in one respect a bit different to `update` and `delete` statements. + +[IMPORTANT] +==== +An `insert` statement is inherently _not_ polymorphic! +Its list of target fields is of fixed length, whereas each subclass of an entity class might declare additional fields. +If the entity is involved in a mapped inheritance hierarchy, only attributes declared directly by the named entity and its superclasses may occur in the list of target fields. +Attributes declared by subclasses may not occur. +==== + +The `queryExpression` in an `insert ... select` statement may be any valid `select` query, with the caveat that the types of the values in the `select` list must match the types of the target fields. + +[NOTE] +==== +This is checked during query compilation rather than allowing the type check to delegate to the database. +This may cause problems when two Java types map to the same database type. +For example, an attribute of type `LocalDateTime` and an attribute or type `Timestamp` both map to the SQL type `timestamp`, but are not considered assignable by the query compiler. +==== + +There are two ways to assign a value to the `@Id` attribute: + +- explicitly specify the id attribute in the list of target fields, and its value in the values assigned to the target fields, or +- omit it, in which case a generated value is used. + +Of course, the second option is only available for entities with database-level id generation (sequences or identity/autoincrement columns). +It's not available for entities whose id generator is implemented in Java, nor for entities whose id is assigned by the application. + +The same two options are available for a `@Version` attribute. +When no version is explicitly specified, the version for a new entity instance is used. + +Like `update` and `delete` statements, an `insert` statement must be executed by calling `Query.executeUpdate()`. + +Now it's time to look at something _much_ more complicated. + +[[select]] +==== Select statements + +Select statements retrieve and analyse data. +This is what we're really here for. + +The full BNF for a `select` query is quite complicated, but there's no need to understand it now. +We're displaying it here for future reference. + +[[select-bnf-example]] +[source, antlrv4] +---- +include::{extrasdir}/statement_select_bnf.txt[] +---- + +Most of the complexity here arises from the interplay of set operators (`union`, `intersect`, and `except`) with sorting. + +We'll describe the various clauses of a query later, in <> and in <>, but for now, to summarize, a query might have these bits: + +[cols="22,22,~"] +|=== +| Clause | Jargon | Purpose + +| `with` | Common table expressions | Declares <> to be used in the following query +| `from` and `join` | Roots and joins | <> the entities involved in the query, and how they're <> to each other +| `where` | Selection/restriction | Specifies a <> on the data returned by the query +| `group by`| Aggregation/grouping | Controls <> +| `having` | Selection/restriction | Specifies a <> to apply _after_ aggregation +| `select` | Projection | Specifies a <> (the things to return from the query) +| `union`, `intersect`, `except` | Set algebra | These are <> applied to the results of multiple subqueries +| `order by` | Ordering | Specifies how the results should be <> +| `limit`, `offset`, `fetch` | Limits | Allows for <> the results +|=== + +Every one of these clauses is optional! + +For example, the simplest query in HQL has no `select` clause at all: + +[[select-simplest-example]] +[source, hql] +---- +from Book +---- + +But we don't necessarily _recommend_ leaving off the `select` list. + +[NOTE] +==== +HQL doesn't require a `select` clause, but JPQL _does_. +==== + +Naturally, the previous query may be written with a `select` clause: + +[source, hql] +---- +select book from Book book +---- + +But when there's no explicit `select` clause, the select list is implied by the result type of the query: + +[source, java] +[%unbreakable] +---- +// result type Book, only the Book selected +List books = + session.createQuery("from Book join authors", Book.class) + .getResultList(); +for (Person person: persons) { + ... +} +---- + +[source, java] +[%unbreakable] +---- +// result type Object[], both Book and Author selected +List booksWithAuthors = + session.createQuery("from Book join authors", Book.class, Object[].class) + .getResultList(); +for (var bookWithAuthor: booksWithAuthors) { + Book book = (Book) bookWithAuthor[0]; + Author author = (Author) bookWithAuthor[1]; + ... +} +---- + +For complicated queries, it's probably best to explicitly specify a `select` list. + +An alternative "simplest" query has _only_ a `select` list: + +[[select-simplest-example-alt]] +[source, hql] +---- +select local datetime +---- + +This results in a SQL `from dual` query (or equivalent). + +[TIP] +==== +Looking carefully at the BNF given above, you might notice that the `select` list may occur either at the beginning of a query, or near the end, right before `order by`. + +Of course, standard SQL, and JPQL, require that the `select` list comes at the beginning. +But it's more natural to put it last: + +[source, hql] +---- +from Book book select book.title, book.isbn +---- + +This form of the query is more readable, because the alias is declared _before_ it's used, just as God and nature intended. +==== + +Of course, queries are always polymorphic. +Indeed, a fairly innocent-looking HQL query can easily translate to a SQL statement with many joins and unions. + +[TIP] +==== +We need to be a _bit_ careful about that, but actually it's usually a good thing. +HQL makes it very easy to fetch all the data we need in a single trip to the database, and that's absolutely key to achieving high performance in data access code. +Typically, it's much worse to fetch exactly the data we need, but in many round trips to the database server, than it is to fetch just a bit more data than what we're going to need, all a single SQL query. +==== \ No newline at end of file diff --git a/documentation/src/main/asciidoc/querylanguage/Expressions.adoc b/documentation/src/main/asciidoc/querylanguage/Expressions.adoc new file mode 100644 index 0000000000..38cab92680 --- /dev/null +++ b/documentation/src/main/asciidoc/querylanguage/Expressions.adoc @@ -0,0 +1,1180 @@ +[[expressions]] +== Expressions + +We now switch gears, and begin describing the language from the bottom up. +The very bottom of a programming language is its syntax for literal values. + +// Essentially, expressions are references that resolve to basic or tuple values. + +[[literals]] +=== Literals + +The most important literal value in this language is `null`. It's assignable to any other type. + +[[boolean-literals]] +==== Boolean literals + +The boolean literal values are the (case-insensitive) keywords `true` and `false`. + +[[string-literals]] +==== String literals + +String literals are enclosed in single quotes. + +[source,hql] +---- +select 'hello world' +---- + +To escape a single quote within a string literal, use a doubled single quote: `''`. + +[[string-literals-example]] +//.String literals examples +[source, hql] +---- +from Book where title like 'Ender''s' +---- + +Alternatively, Java-style double-quoted strings are also allowed, with the usual Java character escape syntax. + +[source,hql] +---- +select "hello\tworld" +---- + +This option is not much used. + +[[numeric-literals]] +==== Numeric literals + +Numeric literals come in several different forms: + +|=== +| Kind | Type | Example + +| Integer literals | `Long`, `Integer`, `BigInteger` | `1`, `3_000_000L`, `2BI` +| Decimal literals | `Double`, `Float`, `BigDecimal` | `1.0`, `123.456F`, `3.14159265BD` +| Hexadecimal literals | `Long`, `Integer` | `0X1A2B`, `0x1a2b` +| Scientific notation | `Double`, `Float`, `BigDecimal` | `1e-6`, `6.674E-11F` +|=== + +For example: + +[[numeric-literals-example]] +[source, hql] +---- +from Book where price < 100.0 +---- +[source, hql] +---- +select author, count(book) +from Author as author + join author.books as book +group by author +having count(book) > 10 +---- + +The type of a numeric literal may be specified using a Java-style postfix: +|=== +| Postfix | Type | Java type + +| `L` or `l` | long integer | `long` +| `D` or `d` | double precision | `double` +| `F` or `f` | single precision | `float` +| `BI` or `bi` | large integer | `BigInteger` +| `BD` or `bd` | exact decimal | `BigDecimal` +|=== + +It's not usually necessary to specify the precision explicitly. + +[NOTE] +==== +In a literal with an exponent, the `E` is case-insensitive. +Similarly, the Java-style postfix is case-insensitive. +==== + +[[datetime-literals]] +==== Date and time literals + +According to the JPQL specification, date and time literals may be specified using the JDBC escape syntax. +Since this syntax is rather unpleasant to look at, HQL provides not one, but two alternatives. + +|=== +| Date/time type | Recommended Java type | JDBC escape syntax πŸ’€| Braced literal syntax | Explicitly typed literal syntax + +| Date | `LocalDate` | `{d 'yyyy-mm-dd'}` | `{yyyy-mm-dd}` | `date yyyy-mm-dd` +| Time | `LocalTime` | `{t 'hh:mm'}` | `{hh:mm}` | `time hh:mm` +| Time with seconds | `LocalTime` | `{t 'hh:mm:ss'}` | `{hh:mm:ss}` | `time hh:mm:ss` +| Datetime | `LocalDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss'}` | `{yyyy-mm-dd hh:mm:ss}` | `datetime yyyy-mm-dd hh:mm:ss` +| Datetime with milliseconds | `LocalDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss.millis'}` | `{yyyy-mm-dd hh:mm:ss.millis}` | `datetime yyyy-mm-dd hh:mm:ss.millis` +| Datetime with an offset | `OffsetDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss+hh:mm'}` | `{yyyy-mm-dd hh:mm:ss +hh:mm}` | `datetime yyyy-mm-dd hh:mm:ss +hh:mm` +| Datetime with a time zone | `OffsetDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss GMT'}` | `{yyyy-mm-dd hh:mm:ss GMT}` | `datetime yyyy-mm-dd hh:mm:ss GMT` +|=== + +Literals referring to the current date and time are also provided. +Again there is some flexibility. + +|=== +| Date/time type | Java type | Underscored syntax | Spaced syntax + +| Date | `java.time.LocalDate` | `local_date` | `local date` +| Time | `java.time.LocalTime` | `local_time` | `local time` +| Datetime | `java.time.LocalDateTime` | `local_datetime` | `local datetime` +| Offset datetime | `java.time.OffsetDateTime`| `offset_datetime` | `offset datetime` +| Instant | `java.time.Instant` | `instant` | `instant` +| Date | `java.sql.Date` πŸ’€| `current_date` | `current date` +| Time | `java.sql.Time` πŸ’€| `current_time` | `current time` +| Datetime | `java.sql.Timestamp` πŸ’€| `current_timestamp` | `current timestamp` +|=== + +Of these, only `local date`, `local time`, `local datetime`, `current_date`, `current_time`, and `current_timestamp` are defined by the JPQL specification. + +[IMPORTANT] +==== +The use of date and time types from the `java.sql` package is strongly discouraged! +Always use `java.time` types in new code. +==== + +[[duration-literals]] +==== Duration literals + +There are two sorts of duration in HQL: + +* _year-day durations_, that is, the length of an interval between two dates, and +* _week-nanosecond durations_, that is, the length of an interval between two datetimes. + +For conceptual reasons, the two kinds of duration cannot be cleanly composed. + +Literal duration expressions are of form `n unit`, for example `1 day` or `10 year` or `100 nanosecond`. + +The unit may be: `day`, `month`, `quarter`, `year`, `second`, `minute`, `hour`, or `nanosecond`. + +[NOTE] +==== +A HQL duration is considered to map to a Java `java.time.Duration`, but semantically they're perhaps more similar to an ANSI SQL `INTERVAL` type. +==== + +[[binary-literals]] +==== Binary string literals + +HQL also provides a choice of formats for binary strings: + +* the braced syntax `{0xDE, 0xAD, 0xBE, 0xEF}`, a list of Java-style hexadecimal byte literals, or +* the quoted syntax `X'DEADBEEF'` or `x'deadbeef'`, similar to SQL. + +[[enum-literals]] +==== Enum literals + +Literal values of a Java enumerated type may be written without needing to specify the enum class name: + +[[enum-example]] +[source, hql] +---- +from Book where status <> OUT_OF_PRINT +---- + +Here, the enum class is inferred from the type of the expression on the left of the comparison operator. + +[[java-constants]] +==== Java constants + +HQL allows any Java `static` constant to be used in HQL, but it must be referenced by its fully-qualified name: + +[[java-constant-example]] +[source, hql] +---- +select java.lang.Math.PI +---- + +[[entity-name-literals]] +==== Literal entity names + +Entity names may also occur as a literal value. They do not need to be qualified. + +[source,hql] +---- +from Payment as payment +where type(payment) = CreditCardPayment +---- + +See <>. + +[[path-expressions]] +=== Identification variables and path expressions + +Identification variables, and path expressions beginning with an identification variable are legal expressions in almost every context. + +[source,hql] +---- +select book.publisher.name from Book book +---- + +See <> and <>. + +=== Operator expressions + +HQL has operators for working with strings, numeric values, and date/time types. + +[[concatenation]] +==== String concatenation + +HQL defines two ways to concatenate strings: + +* the SQL-style concatenation operator, `||`, and +* the JPQL-standard `concat()` function. + +See <> for details of the `concat()` function. + +[[concatenation-example]] +[source, hql] +---- +select book.title || ' by ' || listagg(author.name, ' & ') +from Book as book + join book.authors as author +group by book +---- + +Many more operations on strings are defined below, in <>. + +[[numeric-arithmetic]] +==== Numeric arithmetic + +The basic SQL arithmetic operators, `+`,`-`,`*`, and `/` are joined by the remainder operator `%`. + +[[numeric-arithmetic-example]] +[source, hql] +---- +select (1.0 + :taxRate) * sum(item.book.price * item.quantity) +from Order as ord + join ord.items as item +where ord.id = :oid +---- + +When both operands of a binary numeric operator have the same type, the result type of the whole expression is the same as the operands. + +[WARNING] +==== +Thus, `3/2` performs integer division and evaluates to `1`. +==== + +When the operands are of different type, one of the operands is implicitly converted to _wider_ type, with wideness given, in decreasing order, by the list below: + +- `Double` (widest) +- `Float` +- `BigDecimal` +- `BigInteger` +- `Long` +- `Integer` +- `Short` +- `Byte` + +Many more numeric operations are defined below, in <>. + +[[Datetime-arithmetic]] +==== Datetime arithmetic + +Arithmetic involving dates, datetimes, and durations is quite subtle. +Among the issues to consider are: + +- There's two kinds of duration: year-day, and week-nanosecond durations. +The first is a difference between dates; the second is a difference between datetimes. +- We can subtract dates and datetimes, but we can't add them. +- A Java-style duration has much too much precision, and so in order to use it for anything useful, we must somehow truncate it to something coarser-grained. + +Here we list the basic operations. + +[cols="10,38,~,18"] +|=== +| Operator | Expression type | Example | Resulting type + +| `-` | Difference between two dates | `your.birthday - local date` | year-day duration +| `-` | Difference between two datetimes | `local datetime - record.lastUpdated` | week-nanosecond duration +| `+` | Sum of a date and a year-day duration | `local date + 1 week` | date +| `+` | Sum of a datetime and a week-nanosecond duration | `record.lastUpdated + 1 second` | datetime +| `*` | Product of an integer and a duration | `billing.cycles * 30 day` | duration +| `by unit` | Convert a duration to an integer | `(1 year) by day` | integer +|=== + +The `by unit` operator converts a duration to an integer, for example: `(local date - your.birthday) by day` evaluates to the number of days you still have to wait. + +The function `extract(unit from ...)` extracts a field from a date, time, or datetime type, for example, `extract(year from your.birthday)` produces the year in which you were born, and throws away important information about your birthday. + +[IMPORTANT] +==== +Please carefully note the difference between these two operations: `by` and `extract()` both evaluate to an integer, but they have very different uses. +==== + +Additional datetime operations, including the useful `format()` function, are defined below, in <>. + +[[case-expressions]] +=== Case expressions + +Just like in standard SQL, there are two forms of case expression: + +* the _simple_ case expression, and +* the so-called _searched_ case expression. + +[TIP] +==== +Case expressions are verbose. +It's often simpler to use the `coalesce()`, `nullif()`, or `ifnull()` functions, +as described below in <>. +==== + +[[simple-case-expressions]] +[discrete] +===== Simple case expressions + +The syntax of the simple form is defined by: + +[[simple-case-expressions-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/simple_case_bnf.txt[] +---- + +For example: + +[[simple-case-expressions-example]] +[source, hql] +---- +select + case author.nomDePlume + when '' then person.name + else author.nomDePlume end +from Author as author + join author.person as person +---- + +[[searched-case-expressions]] +[discrete] +===== Searched case expressions + +The searched form has the following syntax: + +[[searched-case-expressions-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/searched_case_bnf.txt[] +---- + +For example: + +[[searched-case-expressions-example]] +[source, hql] +---- +select + case + when author.nomDePlume is null then person.name + else author.nomDePlume end +from Author as author + join author.person as person +---- + +A `case` expression may contain complex expression, including operator expressions. + +[[exp-functions]] +=== Functions + +Both HQL and JPQL define some standard functions and make them portable between databases. + +[%unbreakable] +[TIP] +==== +A program that wishes to remain portable between Jakarta Persistence providers should in principle limit itself to the use of the functions which are blessed by the specification. +Unfortunately, there's not so many of them. +==== + +In some cases, the syntax of these functions looks a bit funny at first, for example, `cast(number as String)`, or `extract(year from date)`, or even `trim(leading '.' from string)`. +This syntax is inspired by standard ANSI SQL, and we promise you'll get used to it. + +[%unbreakable] +[IMPORTANT] +==== +HQL abstracts away from the actual database-native SQL functions, letting you write queries which are portable between databases. + +For some functions, and always depending on the database, a HQL function invocation translates to a quite complicated SQL expression! +==== + +In addition, there are several ways to use a database function that's not known to Hibernate. + +[[functions-typecasts]] +==== Types and typecasts + +The following special functions make it possible to discover or narrow expression types: + +[cols="15,~,~,^15"] +|=== +| Special function | Purpose | Signature | JPA standard + +| `type()` | The (concrete) entity name | `type(e)` | βœ” +| `treat()` | Narrow an entity type | `treat(e as Entity)` | βœ” +| `cast()` | Narrow a basic type | `cast(x as Type)` | βœ– +| `str()` | Cast to a string | `str(x)` | βœ– +|=== + +Let's see what these functions do. + +[[function-type]] +[discrete] +===== Evaluating an entity type + +The function `type()`, applied to an identification variable, evaluates to the entity name of the referenced entity. +This is mainly useful when dealing with entity inheritance hierarchies. + +[[entity-type-exp-example]] +[source, hql] +---- +select payment +from Payment as payment +where type(payment) = CreditCardPayment +---- + +[[function-treat]] +[discrete] +===== Narrowing an entity type + +The function `treat()` may be used to narrow the type of an identification variable. +This is useful when dealing with entity inheritance hierarchies. + +[[treat-example]] +[source, hql] +---- +select payment +from Payment as payment +where length(treat(payment as CreditCardPayment).cardNumber) + between 16 and 20 +---- + +The type of the expression `treat(p as CreditCardPayment)` is the narrowed type, `CreditCardPayment`, instead of the declared type `Payment` of `p`. +This allows the attribute `cardNumber` declared by the subtype `CreditCardPayment` to be referenced. + +The `treat()` function may even occur in a <>. + +[[function-cast]] +[discrete] +===== General typecasts + +The function `cast()` has a similar syntax, but is used to narrow basic types. +Its first argument is usually an attribute of an entity, or a more complex expression involving entity attributes. + +The target type is an unqualified Java class name: +`String`, `Long`, `Integer`, `Double`, `Float`, `Character`, `Byte`, `BigInteger`, `BigDecimal`, `LocalDate`, `LocalTime`, `LocalDateTime`, etc. + +[source, hql] +---- +select cast(id as String) from Order +---- + +[[function-str]] +[discrete] +===== Casting to string + +The function `str(x)` is a synonym for `cast(x as String)`. + +[source, hql] +---- +select str(id) from Order +---- + +[[functions-null]] +==== Functions for working with null values + +The following functions make it easy to deal with null values: + +[cols="15,~,~,^15"] +|=== +| Function | Purpose | Signature | JPA standard + +| `coalesce()` | First non-null argument | `coalesce(x, y, z)` | βœ” +| `ifnull()` | Second argument if first is null | `ifnull(x,y)` | βœ– +| `nullif()` | `null` if arguments are equal | `nullif(x,y)` | βœ” +|=== + +[discrete] +===== Handling null values + +An abbreviated `case` expression that returns the first non-null operand. + +[[coalesce-example]] +[source, hql] +---- +select coalesce(author.nomDePlume, person.name) +from Author as author + join author.person as person +---- + +[discrete] +===== Handling null values + +HQL allows `ifnull()` as a synonym for `coalesce()` in the case of exactly two arguments. + +[[ifnull-example]] +[source, hql] +---- +select ifnull(author.nomDePlume, person.name) +from Author as author + join author.person as person +---- + +[discrete] +===== Producing null values + +Evaluates to null if its operands are equal, or to its first argument otherwise. + +[[nullif-example]] +[source, hql] +---- +select ifnull(nullif(author.nomDePlume, person.name), 'Real name') +from Author as author + join author.person as person +---- + +[[functions-datetime]] +==== Functions for working with dates and times + +There are some very important functions for working with dates and times. + +[cols="15,~,~,^15"] +|=== +| Special function | Purpose | Signature | JPA standard + +| `extract()` | Extract a datetime field | `extract(field from x)` | βœ” +| `format()` | Format a datetime as a string | `format(datetime as pattern)` | βœ– +| `trunc()` or `truncate()` | Datetime truncation | `truncate(datetime, field)` | βœ– +|=== + +[[function-extract]] +[discrete] +===== Extracting date and time fields + +The special function `extract()` obtains a single field of a date, time, or datetime. + +Field types include: `day`, `month`, `year`, `second`, `minute`, `hour`, `day of week`, `day of month`, `week of year`, `date`, `time`, `epoch` and more. +For a full list of field types, see the Javadoc for https://docs.jboss.org/hibernate/orm/{majorMinorVersion}/javadocs/org/hibernate/query/TemporalUnit.html[`TemporalUnit`]. + +[source, hql] +---- +from Order where extract(date from created) = local date +---- +[source, hql] +---- +select extract(year from created), extract(month from created) from Order +---- + +The following functions are abbreviations for `extract()`: + +[cols="15,~,^15"] +|=== +| Function | Long form using `extract()` | JPA standard + +| `year(x)` | `extract(year from x)` | βœ– +| `month(x)` | `extract(month from x)` | βœ– +| `day(x)` | `extract(day from x)` | βœ– +| `hour(x)` | `extract(year from x)` | βœ– +| `minute(x)` | `extract(year from x)` | βœ– +| `second(x)` | `extract(year from x)` | βœ– +|=== + +TIP: These abbreviations aren't part of the JPQL standard, but on the other hand they're a lot less verbose. + +[source, hql] +---- +select year(created), month(created) from Order +---- + +[[function-format]] +[discrete] +===== Formatting dates and times + +This function formats a date, time, or datetime according to a pattern. + +The syntax is `format(datetime as pattern)`, and the pattern must be written in a subset of the pattern language defined by Java's `java.time.format.DateTimeFormatter`. + +For a full list of `format()` pattern elements, see the Javadoc for https://docs.jboss.org/hibernate/orm/{majorMinorVersion}/javadocs/org/hibernate/dialect/Dialect.html#appendDatetimeFormat[`Dialect.appendDatetimeFormat`]. + +[[function-trunc-datetime]] +[discrete] +===== Truncating a date or time type + +This function truncates a date, time, or datetime to the temporal unit specified by field. + +The syntax is `truncate(datetime, field)`. Supported temporal units are: `year`, `month`, `day`, `hour`, `minute` or `second`. + +Truncating a date, time or datetime value translates to obtaining a value of the same type in which all temporal units smaller than `field` have been pruned. +For hours, minutes and second this means setting them to `00`. For months and days, this means setting them to `01`. + +[[string-functions]] +==== Functions for working with strings + +Naturally, there are a good number of functions for working with strings. + +[cols="15,~,~,^15"] +|=== +| Function | Purpose | Syntax | JPA standard / ANSI SQL Standard + +| `upper()` | The string, with lowercase characters converted to uppercase | `upper(s)` | βœ” / βœ” +| `lower()` | The string, with uppercase characters converted to lowercase | `lower(s)` | βœ” / βœ” +| `length()` | The length of the string | `length(s)` | βœ” / βœ– +| `concat()` | Concatenate strings | `concat(x, y, z)` | βœ” / βœ– +| `locate()` | Location of string within a string | `locate(s, d)`, + +`locate(s, d, i)` | βœ” / βœ– +| `position()` | Similar to `locate()` | `position(pattern in string)` | βœ– / βœ” +| `substring()` | Substring of a string (JPQL-style) | `substring(s, i)`, + +`substring(s, i, l)` | βœ” / βœ– +| `substring()` | Substring of a string (ANSI SQL-style) +| `substring(string from start)`, + +`substring(string from start for length)` | βœ– / βœ” +| `trim()` | Trim characters from string | See below | βœ” / βœ” +| `overlay()` | For replacing a substring +| `overlay(string placing replacement from start)`, + +`overlay(string placing replacement from start for length)` | βœ– / βœ” +| `pad()` | Pads a string with whitespace, or with a specified character +| `pad(string with length)`, + +`pad(string with length leading)`, + +`pad(string with length trailing)`, or + +`pad(string with length leading character)` | βœ– / βœ– +| `left()` | The leftmost characters of a string | `left(string, length)` | βœ– / βœ– +| `right()` | The rightmost characters of a string | `right(string, length)` | βœ– / βœ– +| `replace()` | Replace every occurrence of a pattern in a string | `replace(string, pattern, replacement)` | βœ– / βœ– +| `repeat()` | Concatenate a string with itself multiple times | `replace(string, times)` | βœ– / βœ– +| `collate()` | Select a collation | `collate(p.name as collation)` | βœ– / βœ– +|=== + +Let's take a closer look at just some of these. + +[IMPORTANT] +==== +Contrary to Java, positions of characters within strings are indexed from 1 instead of 0! +==== + +[discrete] +===== Concatenating strings + +Accepts a variable number of arguments, and produces a string by concatenating them. + +[source, hql] +---- +select concat(book.title, ' by ', listagg(author.name, ' & ')) +from Book as book + join book.authors as author +group by book +---- + +[discrete] +===== Finding substrings +The JPQL function `locate()` determines the position of a substring within another string. + +- The optional third argument is used to specify a position at which to start the search. + +[source, hql] +---- +select locate('Hibernate', title) from Book +---- + +[discrete] +===== Finding substrings + +The `position()` function has a similar purpose, but follows the ANSI SQL syntax. + +[source, hql] +---- +select position('Hibernate' in title) from Book +---- + +[discrete] +===== Slicing strings +Returns a substring of the given string. + +- The second argument specifies the position of the first character of the substring. +- The optional third argument specifies the maximum length of the substring. + +[source, hql] +---- +select substring(title, 0, position(' for Dummies')) from Book +---- + +[discrete] +===== Trimming strings +The `trim()` function follows the syntax and semantics of ANSI SQL. +It may be used to trim `leading` characters, `trailing` characters, or both. + +[source, hql] +---- +select trim(title) from Book +---- +[source, hql] +---- +select trim(trailing ' ' from text) from Book +---- + +Its BNF is funky: + +[source, antlrv4] +---- +trimFunction + : "TRIM" "(" trimSpecification? trimCharacter? "FROM"? expression ")" ; +trimSpecification + : "LEADING" | "TRAILING" | "BOTH" ; +---- + +[discrete] +===== Collations + +Selects a collation to be used for its string-valued argument. +Collations are useful for <> with `<` or `>`, and in the <>. + +For example, `collate(p.name as ucs_basic)` specifies the SQL standard collation `ucs_basic`. + +IMPORTANT: Collations aren't very portable between databases. + +[[functions-numeric]] +==== Numeric functions + +Of course, we also have a number of functions for working with numeric values. + +[cols="15,~,~,^15"] +|=== +| Function | Purpose | Signature | JPA standard + +| `abs()` | The magnitude of a number | `abs(x)` | βœ” +| `sign()` | The sign of a number | `sign(x)` | βœ” +| `mod()` | Remainder of integer division | `mod(n,d)` | βœ” +| `sqrt()` | Square root of a number | `sqrt(x)` | βœ” +| `exp()` | Exponential function | `exp(x)` | βœ” +| `power()` | Exponentiation | `power(x,y)` | βœ” +| `ln()` | Natural logarithm | `ln(x)` | βœ” +| `round()` | Numeric rounding | `round(number)`, + +`round(number, places)` | βœ” +| `trunc()` or `truncate()` | Numeric truncation | `truncate(number)`, + +`truncate(number, places)` | βœ– +| `floor()` | Floor function | `floor(x)` | βœ” +| `ceiling()` | Ceiling function | `ceiling(x)` | βœ” + +| `log10()` | Base-10 logarithm | `log10(x)` | βœ– +| `log()` | Arbitrary-base logarithm | `log(b,x)` | βœ– +| `pi` | π | `pi` | βœ– +| `sin()`, `cos()`, `tan()`, `asin()`, `acos()`, `atan()` +| Basic trigonometric functions | `sin(theta)`, `cos(theta)` | βœ– +| `atan2()` | Two-argument arctangent (range `(-π,π]`) | `atan2(y, x)` | βœ– +| `sinh()`, `cosh()`, `tanh()` | Hyperbolic functions | `sinh(x)`, `cosh(x)`, `tanh(x)` | βœ– +| `degrees()` | Convert radians to degrees | `degrees(x)` | βœ– +| `radians()` | Convert degrees to radians | `radians(x)` | βœ– +| `least()` | Return the smallest of the given arguments | `least(x, y, z)` |βœ– +| `greatest()` | Return the largest of the given arguments | `greatest(x, y, z)` | βœ– +|=== + +We haven't included <>, <>, or <> +in this list, because their purpose is more specialized, and because they come with extra special syntax. + +[[functions-collections]] +==== Functions for dealing with collections + +The following functions apply to any identification variable that refers to a joined collection or many-valued association. + +[[collection-functions]] +[cols="12,20,~,^15"] +|=== +| Function | Applies to | Purpose | JPA standard + +| `size()` | Any collection | The size of a collection | βœ– +| `element()` | Any collection | The element of a list | βœ– +| `index()`| Lists | The index of a list element | βœ– +| `key()`| Maps | The key of a map entry | βœ– +| `value()`| Maps | The value of a map entry | βœ– +| `entry()`| Maps | The whole entry in a map | βœ– +|=== + +[discrete] +===== Collection sizes + +The number of elements of a collection or to-many association. + +[[size-example]] +[source, hql] +---- +select name, size(books) from Author +---- + +[[list-functions]] +[discrete] +===== List elements and indexes + +A reference to an element or index of <>. + +[[map-functions]] +[discrete] +===== Map keys, values, and entries + +A reference to a key, value, or entry of a <>. + +[[elements-indices]] +==== Quantification over collections + +There's two additional functions of collections which we didn't include in previous table because they're much less-used and a bit harder to understand. + +[cols="12,30,~"] +|=== +| HQL Function | Applies to | Purpose + +| `elements()` | Any collection | Refers to the elements of a collection as a whole + +| `indices()` | Indexed collections (lists and maps) | Similar to `elements()` but refers to the collections indices (keys/positions) as a whole +|=== + +The `elements()` and `indices()` functions give us a shortcut way to write a subquery: +We may use these functions with: + +- an <> or <> predicate, +- a <>, or +- an <>. + +[cols="35,~"] +|=== +| Shortcut | Equivalent subquery + +| `exists elements(book.editions)` | `exists (select ed from book.editions as ed)` +| `2 in indices(book.editions)` | `2 in (select index(ed) from book.editions as ed)` +| `10 > all(elements(book.printings))` | `10 > all(select pr from book.printings as pr)` +| `max(elements(book.printings))` | `(select max(pr) from book.printings as pr)` +|=== + +These functions are most useful with ``@ElementCollection``s. + +[[functions-model]] +==== Functions for working with ids and versions + +Finally, the following functions evaluate the id, version, or natural id of an entity, or the foreign key of a to-one association: + +[[model-functions]] +[cols="12,~,^15"] +|=== +| Function | Purpose | JPA standard + +| `id()` | The value of the entity `@Id` attribute. | βœ– +| `version()` | The value of the entity `@Version` attribute. | βœ– +| `naturalid()` | The value of the entity `@NaturalId` attribute. | βœ– +| `fk()` | The value of the foreign key column mapped by a `@ManyToOne` (or logical `@OneToOne`) association. +Useful with associations annotated `@NotFound`. | βœ– +|=== + +[[user-defined-functions]] +==== Native and user-defined functions + +The functions we've described above are the functions abstracted by HQL and made portable across databases. +But, of course, HQL can't abstract every function in your database. + +There are several ways to call native or user-defined SQL functions. + +- A native or user-defined function may be called using JPQL's `function` syntax, for example, ``function('sinh', phi)``. +(This is the easiest way, but not the best way.) +- A user-written `FunctionContributor` may register user-defined functions. +- A custom `Dialect` may register additional native functions by overriding `initializeFunctionRegistry()`. + +[TIP] +==== +Registering a function isn't hard, but is beyond the scope of this chapter. + +(It's even possible to use the APIs Hibernate provides to make your own _portable_ functions!) +==== + +Fortunately, every built-in `Dialect` already registers many native functions for the database it supports. + +[TIP] +==== +Try setting the log category `org.hibernate.HQL_FUNCTIONS` to debug. +Then at startup Hibernate will log a list of type signatures of all registered functions. +==== + + +[[function-sql]] +==== Embedding native SQL in HQL + +The special function `sql()` allows the use of native SQL fragments inside an HQL query. + +The signature of this function is `sql(pattern[, argN]*)`, where `pattern` must be a string literal but the remaining arguments may be of any type. +The pattern literal is unquoted and embedded in the generated SQL. +Occurrences of `?` in the pattern are replaced with the remaining arguments of the function. + +We may use this, for example, to perform a native PostgreSQL typecast: +[source, hql] +---- +from Computer c where c.ipAddress = sql('?::inet', '127.0.0.1') +---- +This results in SQL logically equivalent to: +[source, sql] +---- +select * from Computer c where c.ipAddress = '127.0.0.1'::inet +---- +Or we can use a native SQL operator: +[source, hql] +---- +from Human h order by sql('(? <-> ?)', h.workLocation, h.homeLocation) +---- +And this time the SQL is logically equivalent to: +[source, sql] +---- +select * from Human h where (h.workLocation <-> h.homeLocation) +---- + +[[conditional-expressions]] +=== Predicates + +A predicate is an operator which, when applied to some argument, evaluates to `true` or `false`. +In the world of SQL-style ternary logic, we must expand this definition to encompass the possibility that the predicate evaluates to `null`. +Typically, a predicate evaluates to `null` when one of its arguments is `null`. + +Predicates occur in the `where` clause, the `having` clause and in searched case expressions. + +[[relational-comparisons]] +==== Comparison operators + +The binary comparison operators are borrowed from SQL: `=`, `>`, `>=`, `<`, `\<=`, `<>`. + +TIP: If you prefer, HQL treats `!=` as a synonym for `<>`. + +The operands should be of the same type. + +[[relational-comparisons-example]] +[source, hql] +---- +from Book where price < 1.0 +---- +[source, hql] +---- +from Author as author where author.nomDePlume <> author.person.name +---- +[source, hql] +---- +select id, total +from ( + select ord.id as id, sum(item.book.price * item.quantity) as total + from Order as ord + join Item as item + group by ord +) +where total > 100.0 +---- + +[[between-predicate]] +==== `between` predicate + +The ternary `between` operator, and its negation, `not between`, determine if a value falls within a range. + +Of course, all three operands must be of compatible type. + +[[between-predicate-example]] +[source, hql] +---- +from Book where price between 1.0 and 100.0 +---- + +[[null-predicate]] +==== Operators for dealing with null + +The following operators make it easier to deal with null values. + +[cols="20,20,15,~"] +|=== +| Operator | Negation | Type | Semantics + +| `is null` | `is not null` | Unary postfix | `true` if the value to the left is null +| `is distinct from` | `is not distinct from` | Binary | `true` if the value on the left is equal to the value on the right, or if both are null +|=== + +[[null-predicate-example]] +[source, hql] +---- +from Author where nomDePlume is not null +---- + +[[like-predicate]] +==== String pattern matching + +The `like` operator performs pattern matching on strings. +Its friend `ilike` performs case-insensitive matching. + +Their syntax is defined by: + +[[like-predicate-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/predicate_like_bnf.txt[] +---- + +The expression on the right is a pattern, where: + +* `_` matches any single character, +* `%` matches any number of characters, and +* if an escape character is specified, it may be used to escape either of these wildcards. + +[[like-predicate-example]] +[source, hql] +---- +from Book where title not like '% for Dummies' +---- + +The optional `escape` character allows a pattern to include a literal `_` or `%` character. + +As you can guess, `not like` and `not ilike` are the enemies of `like` and `ilike`, and evaluate to the exact opposite boolean values. + +[[in-predicate]] +==== `in` predicate + +The `in` predicates evaluates to true if the value to its left is in ... well, whatever it finds to its right. + +Its syntax is unexpectedly complicated: + +[[in-predicate-bnf]] +[source, antlrv4, indent=0] +---- +include::{extrasdir}/predicate_in_bnf.txt[] +---- + +This less-than-lovely fragment of the HQL ANTLR grammar tells us that the thing to the right might be: + +- a list of values enclosed in parentheses, +- a subquery, +- one of the functions `elements()` or `indices()` defined <>, or +- a query parameter, + +The type of the expression on the left, and the types of all the values on the right must be compatible. + +[%unbreakable] +[NOTE] +==== +JPQL limits the legal types to string, numeric, date/time, and enum types, and in JPQL the left expression must be either: + +- a _state field_, which means a basic attribute, excluding associations and embedded attributes, or +- an <>. + +HQL is far more permissive. HQL itself does not restrict the type in any way, though the database itself might. +Even embedded attributes are allowed, although that feature depends on the level of support for tuple or "row value" constructors in the underlying database. +==== + +[[in-predicate-example]] +[source, hql] +---- +from Payment as payment +where type(payment) in (CreditCardPayment, WireTransferPayment) +---- +[source, hql] +---- +from Author as author +where author.person.name in (select name from OldAuthorData) +---- + +This example doesn't work on every database: + +[source, hql] +---- +from Author as author +where (author.person.name, author.person.birthdate) + in (select name, birthdate from OldAuthorData) +---- + +Here we used a "row value" constructor, a seemingly pretty basic feature which is surprisingly-poorly supported. + +[TIP] +==== +Here's a very useful idiom: +[source,java] +---- +List books = + session.createSelectionQuery("from Book where isbn in :isbns", Book.class) + .setParameterList("isbns", listOfIsbns) + .getResultList(); +---- +==== + +[[relational-comparisons-subqueries]] +==== Comparison operators and subqueries + +The binary comparisons we met <> may involve a quantifier, either: + +- a quantified subquery, or +- a quantifier applied to one of the functions `elements()` or `indices()` defined <>. + +The quantifiers are unary prefix operators: `all`, `every`, `any`, and `some`. + +[cols="10,10,~"] +|=== +| Subquery operator | Synonym | Semantics + +| `every` | `all` | Evaluates to true of the comparison is true for _every_ value in the result set of the subquery +| `any` | `some` | Evaluates to true of the comparison is true for _at least one_ value in the result set of the subquery +|=== + +[[all-subquery-comparison-qualifier-example]] +[source, hql] +---- +from Publisher pub where 100.0 < all(select price from pub.books) +---- + +[[collection-expressions-all-some-example]] +[source, hql] +---- +from Publisher pub where :title = some(select title from pub.books) +---- + +[[exists-predicate]] +==== `exists` predicate + +The unary prefix `exists` operator evaluates to true if the thing to its right is nonempty. + +The thing to its right might be: + +- a subquery, or +- one of the functions `elements()` or `indices()` defined <>. + +As you can surely guess, `not exists` evaluates to true if the thing to the right _is_ empty. + +[[collection-expressions-exists-example]] +[source, hql] +---- +from Author where exists elements(books) +---- +[source, hql] +---- +from Author as author +where exists ( + from Order join items + where book in elements(author.books) +) +---- + + +[[collection-operators]] +==== Collection predicates + +The following operators apply to collection-valued attributes and to-many associations. + +[cols="15,15,20,~"] +|=== +| Operator | Negation | Type | Semantics + +| `is empty` | `is not empty` | Unary postfix | `true` if the collection or association on the left has no elements +| `member of` | `not member of` | Binary | `true` if the value on the left is a member of the collection or association on the right +|=== + +[[empty-collection-predicate-example]] +[source, hql] +---- +from Author where books is empty +---- + +[[member-of-collection-predicate-example]] +[source, hql] +---- +from Author as author, Book as book +where author member of book.authors +---- + + +[[logical-operators]] +==== Logical operators + +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. diff --git a/documentation/src/main/asciidoc/querylanguage/From.adoc b/documentation/src/main/asciidoc/querylanguage/From.adoc new file mode 100644 index 0000000000..128eac0767 --- /dev/null +++ b/documentation/src/main/asciidoc/querylanguage/From.adoc @@ -0,0 +1,572 @@ +[[root-entities-and-joins]] +== Root entities and joins + +The `from` clause, and its subordinate `join` clauses sit right at the heart of most queries. + +[[from-clause]] +=== Declaring root entities + +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_. + +[[identification-variables]] +==== Identification variables + +An identification variable is just a name we can use to refer to an entity and its attributes from expressions in the query. +It may be any legal Java identifier. +According to the JPQL specification, identification variables must be treated as case-insensitive language elements. + +[TIP] +==== +The identification variable is actually optional, but for queries involving more than one entity it's almost always a good idea to declare one. + +This _works_, but it isn't particularly good form: +[source,hql] +---- +from Publisher join books join authors join person where ssn = :ssn +---- +==== + +Identification variables may be declared with the `as` keyword, but this is optional. + +[[root-reference]] +==== Root entity references + +A root entity reference, or what the JPQL specification calls a _range variable declaration_, is a direct reference to a mapped `@Entity` type by its entity name. + +[TIP] +==== +Remember, the _entity name_ is the value of the `name` member of the `@Entity` annotation, or the unqualified Java class name by default. +==== + +[[root-reference-jpql-example]] +[source, hql] +---- +select book from Book as book +---- + +In this example, `Book` is the entity name, and `book` is the identification variable. +The `as` keyword is optional. + +Alternatively, a fully-qualified Java class name may be specified. +Then Hibernate will query every entity which inherits the named type. + +[[root-reference-jpql-fqn-example]] +[source, hql] +---- +select doc from org.hibernate.example.AbstractDocument where text like :pattern +---- + +Of course, there may be multiple root entities. + +[[multiple-root-reference-jpql-example]] +[source, hql] +---- +select a, b +from Author a, Author b, Book book +where a in elements(book.authors) + and b in elements(book.authors) +---- + +This query may even be written using the syntax `cross join` in place of the commas: + +[[cross-join-jpql-example]] +[source, hql] +---- +select a, b +from Book book + cross join Author a + cross join Author b +where a in elements(book.authors) + and b in elements(book.authors) +---- + +Of course, it's possible to write old-fashioned pre-ANSI-era joins: + +[source, hql] +---- +select book.title, publisher.name +from Book book, Publisher publisher +where book.publisher = publisher + and book.title like :titlePattern +---- + +But we never write HQL this way. + +[[polymorphism]] +==== Polymorphism + +HQL and JPQL queries are inherently polymorphic. +Consider: + +[[polymorphism-example]] +[source, hql] +---- +select payment from Payment as payment +---- + +This query names the `Payment` entity explicitly. +But the `CreditCardPayment` and `WireTransferPayment` entities inherit `Payment`, and so `payment` ranges over all three types. +Instances of all these entities are returned by the query. + +[NOTE] +==== +The query `from java.lang.Object` is completely legal. (But not very useful!) + +It returns every object of every mapped entity type. +==== + +// This behavior may be slightly adjusted using the `@Polymorphism` annotation. +// +// See <> for more. + +[[derived-root]] +==== Derived roots + +A _derived root_ is an uncorrelated subquery which occurs in the `from` clause. + +[[derived-root-example]] +[source, hql] +---- +select id, total +from ( + select ord.id as id, sum(item.book.price * item.quantity) as total + from Order as ord + join Item as item + group by ord +) +where total > 100.0 +---- + +The derived root may declare an identification variable. + +[source, hql] +---- +select stuff.id, stuff.total +from ( + select ord.id as id, sum(item.book.price * item.quantity) as total + from Order as ord + join Item as item + group by ord +) as stuff +where total > 100.0 +---- + +This feature can be used to break a more complicated query into smaller pieces. + +[IMPORTANT] +==== +We emphasize that a derived root must be an _uncorrelated_ subquery. +It may not refer to other roots declared in the same `from` clause. +==== + +A subquery may also occur in a <>, in which case it may be a correlated subquery. + +[[from-cte]] +==== Common table expressions in `from` clause + +A _common table expression (CTE)_ is like a derived root with a name. +We'll discuss CTEs <>. + +[[join]] +=== 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. + +An explicit join may be either: + +* an _inner join_, written as `join` or `inner join`, +* a _left outer join_, written as `left join` or `left outer join`, +* a _right outer join_, written as `right join` or `right outer join`, or +* a _full outer join_, written as `full join` or `full outer join`. + +[[root-join]] +==== Explicit root joins + +An explicit root join works just like an ANSI-style join in SQL. + +[[explicit-root-join-example]] +[source, hql] +---- +select book.title, publisher.name +from Book book + join Publisher publisher + on book.publisher = publisher +where book.title like :titlePattern +---- + +The join condition is written out explicitly in the `on` clause. + +[NOTE] +==== +This looks nice and familiar, but it's _not_ the most common sort of join in HQL or JPQL. +==== + +[[explicit-join]] +==== Explicit association joins + +Every explicit association join specifies an entity attribute to be joined. +The specified attribute: + +* is usually a `@OneToMany`, `@ManyToMany`, `@OneToOne`, or `@ManyToOne` association, but +* it could be an `@ElementCollection`, and +* it might even be an attribute of embeddable type. + +In the case of an association or collection, the generated SQL will have a join of the same type. +(For a many-to-many association it will have _two_ joins.) +In the case of an embedded attribute, the join is purely logical and does not result in a join in the generated SQL. + +An explicit join may assign an identification variable to the joined entity. + +[[explicit-inner-join-example]] +[source, hql] +---- +from Book as book + join book.publisher as publisher + join book.authors as author +where book.title like :titlePattern +select book.title, author.name, publisher.name +---- + +For an outer join, we must write our query to accommodate the possibility that the joined association is missing. + +[[explicit-outer-join-example]] +[source, hql] +---- +from Book as book + left join book.publisher as publisher + join book.authors as author +where book.title like :titlePattern +select book.title, author.name, ifnull(publisher.name, '-') +---- + +For further information about collection-valued association references, see <>. + +[[explicit-join-conditions]] +==== Explicit association joins with join conditions + +The `with` or `on` clause allows explicit qualification of the join conditions. + +[NOTE] +==== +The specified join conditions are _added_ to the join conditions specified by the foreign key association. +That's why, historically, HQL uses the keword `with` here: +"with" emphasizes that the new condition doesn't _replace_ the original join conditions. + +The `with` keyword is specific to Hibernate. JPQL uses `on`. +==== + +Join conditions occurring in the `with` or `on` clause are added to the `on` clause in the generated SQL. + +[[explicit-join-with-example]] +[source, hql] +---- +from Book as book + left join book.publisher as publisher + with publisher.closureDate is not null + left join book.authors as author + with author.type <> COLLABORATION +where book.title like :titlePattern +select book.title, author.name, publisher.name +---- + +// The following query is arguably less clear, but it's semantically identical: +// +// [[explicit-join-jpql-on-example]] +// [source, hql] +// ---- +// from Book as book +// left join book.publisher as publisher +// on publisher.closureDate is not null +// left join book.authors as author +// on author.type <> COLLABORATION +// where book.title like :titlePattern +// select book.title, author.name, publisher.name +// ---- + +[[explicit-fetch-join]] +==== Association fetching + +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β€”for lovers of verbosityβ€”``left outer join fetch``, returns all the base entities, including those which have no associated joined entity. + +[IMPORTANT] +==== +This is one of the most important features of Hibernate. +To achieve acceptable performance with HQL, you'll need to use `join fetch` quite often. +Without it, you'll quickly run into the dreaded "n+1 selects" problem. +==== + +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: + +[[explicit-fetch-join-example]] +[source, hql] +---- +select book +from Book as book + left join fetch book.publisher + join fetch book.authors +---- + +In this example, we used a left outer join for `book.publisher` because we also wanted to obtain books with no publisher, but a regular inner join for `book.authors` because every book has at least one author. + +A query may have more than one fetch join, but be aware that: + +* 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 ``join fetch``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 usually be avoided in limited or paged queries. +This includes: + +- queries executed with limits specified via the `setFirstResult()` and `setMaxResults()` methods of `Query`, or +- queries with a limit or offset declared in HQL, described below in <>. + +Nor should they be used with the `scroll()` and `stream()` methods of the `Query` interface. +==== + +Fetch joins are disallowed in subqueries, where they would make no sense. + +[[join-treat]] +==== Joins with typecasts + +An explicit join may narrow the type of the joined entity using `treat()`. + +[[join-treat-example]] +[source, hql] +---- +from Order as ord + join treat(ord.payments as CreditCardPayment) as creditCardPayment +where length(creditCardPayment.cardNumber) between 16 and 20 +---- + +Here, the identification variable `ccp` declared to the right of `treat()` has the narrowed type `CreditCardPayment`, instead of the declared type `Payment`. +This allows the attribute `cardNumber` declared by the subtype `CreditCardPayment` to be referenced in the rest of the query. + +See <> for more information about `treat()`. + +[[join-derived]] +==== Subqueries in joins + +A `join` clause may contain a subquery, either: + +- an uncorrelated subquery, which is almost the same as a <>, except that it may have an `on` restriction, or +- a _lateral join_, which is a correlated subquery, and may refer to other roots declared earlier in the same `from` clause. + +The `lateral` keyword just distinguishes the two cases. + +[[derived-join-example]] +[source, hql] +---- +from Phone as phone + left join ( + select call.duration as duration, call.phone.id as cid + from Call as call + order by call.duration desc + limit 1 + ) as longest on cid = phone.id +where phone.number = :phoneNumber +select longest.duration +---- + +This query may also be expressed using a `lateral` join: + +[source, hql] +---- +from Phone as phone + left join lateral ( + select call.duration as duration + from phone.calls as call + order by call.duration desc + limit 1 + ) as longest +where phone.number = :phoneNumber +select longest.duration +---- + +A lateral join may be an inner or left outer join, but not a right join, nor a full join. + +[TIP] +==== +Traditional SQL doesn't allow correlated subqueries in the `from` clause. +A lateral join is essentially just that, but with a different syntax to what you might expect. + +On some databases, `join lateral` is written `cross apply`. +And on Postgres it's plain `lateral`, without `join`. + +It's almost as if they're _deliberately trying_ to confuse us. +==== + +Lateral joins are particularly useful for computing top-N elements of multiple groups. + +[IMPORTANT] +==== +Most databases support some flavor of `join lateral`, and Hibernate emulates the feature for databases which don't. +But emulation is neither very efficient, nor does it support all possible query shapes, so it's important to test on your target database. +==== + +[[implicit-join]] +==== Implicit association joins (path expressions) + +It's not necessary to explicitly `join` every entity that occurs in a query. +Instead, entity associations may be _navigated_, just like in Java: + +* if an attribute is of embedded type, or is a to-one association, it may be further navigated, but +* if an attribute is of basic type, it is considered terminal, and may not be further navigated, and +* if an attribute is collection-valued, or is a to-many association, it may be navigated, but only with the help of `value()`, `element()`, or `key()`. + +It's clear that: + +* A path expression like `author.name` with only two elements just refers to state held directly by an entity with an alias `author` defined in `from` or `join`. +* But a longer path expression, for example, `author.person.name`, might refer to state held by an associated entity. +(Alternatively, it might refer to state held by an embedded class.) + +In the second case, Hibernate with automatically add a join to the generated SQL if necessary. + +[[implicit-join-example]] +[source, hql] +---- +from Book as book +where book.publisher.name like :pubName +---- + +As in this example, implicit joins usually appear outside the `from` clause of the HQL query. +However, they always affect the `from` clause of the SQL query. + +The example above is equivalent to: + +[[implicit-join-alt]] +[source, hql] +[%unbreakable] +---- +select book +from Book as book + join book.publisher pub +where pub.name like :pubName +---- + +Note that: + +* Implicit joins are always treated as inner joins. +* Multiple occurrences of the same implicit join always refer to the same SQL join. + +This query: + +[[implicit-join-alias-example]] +[source, hql] +---- +select book +from Book as book +where book.publisher.name like :pubName + and book.publisher.closureDate is null +---- + +results in just one SQL join, and is just a different way to write: + +[[implicit-join-alias-alt]] +[source, hql] +---- +select book +from Book as book + join book.publisher as pub +where pub.name like :pubName + and pub.closureDate is null +---- + +[[collection-valued-associations]] +==== Joining collections and many-valued associations + +When a join involves a collection or many-valued association, the declared identification variable refers to the _elements_ of the collection, that is: + +- to the elements of a `Set`, +- to the elements of a `List`, not to their indices in the list, or +- to the values of a `Map`, not to their keys. + +[[collection-valued-associations-example]] +[source, hql] +---- +select publisher.name, author.name +from Publisher as publisher + join publisher.books as book + join book.authors author +where author.name like :namePattern +---- + +In this example, the identification variable `author` is of type `Author`, the element type of the list `Book.authors`. +But if we need to refer to the index of an `Author` in the list, we need some extra syntax. + +You might recall that we mentioned <> and <> a bit earlier. +These functions may be applied to the identification variable declared in a collection join or many-valued association join. + +[cols="12,20,~,~"] +|=== +| Function | Applies to | Interpretation | Notes + +| `value()` or `element()` | Any collection | The collection element or map entry value +| Often optional. +| `index()` | Any `List` with an index column | The index of the element in the list +| For backward compatibility, it's also an alternative to ``key()``, when applied to a map. +| `key()` | Any `Map` | The key of the entry in the list | If the key is of entity type, it may be further navigated. +| `entry()` | Any `Map` | The map entry, that is, the `Map.Entry` of key and value. +| Only legal as a terminal path, and only allowed in the `select` clause. +|=== + +In particular, `index()` and `key()` obtain a reference to a list index or map key. + +[[collection-qualification-example]] +[source, hql] +[%unbreakable] +---- +select book.title, author.name, index(author) +from Book as book + join book.authors as author +---- +[source, hql] +[%unbreakable] +---- +select publisher.name, leadAuthor.name +from Publisher as publisher + join publisher.books as book + join book.authors leadAuthor +where leadAuthor.name like :namePattern + and index(leadAuthor) == 0 +---- + + +[[implicit-collection-join]] +==== Implicit joins involving collections + +A path expression like `book.authors.name` is not considered legal. +We can't just navigate a many-valued association with this syntax. + +Instead, the functions `element()`, `index()`, `key()`, and `value()` may be applied to a path expression to express an implicit join. +So we must write `element(book.authors).name`. + +[[collection-implicit-join-example]] +[source, hql] +---- +select book.title, element(book.authors).name, index(book.authors) +from Book book +---- + +An element of an indexed collection (an array, list, or map) may even be identified using the index operator: + +[[collection-index-operator-example]] +[source, hql] +---- +select publisher.name, book.authors[0].name +from Publisher as publisher + join publisher.books as book +where book.authors[0].name like :namePattern +---- diff --git a/documentation/src/main/asciidoc/querylanguage/Hibernate_Query_Language.adoc b/documentation/src/main/asciidoc/querylanguage/Hibernate_Query_Language.adoc index 48d115288d..c6dab4c943 100644 --- a/documentation/src/main/asciidoc/querylanguage/Hibernate_Query_Language.adoc +++ b/documentation/src/main/asciidoc/querylanguage/Hibernate_Query_Language.adoc @@ -22,3353 +22,23 @@ Gavin King and the Hibernate team <<< -[[preface]] -== Preface - -Hibernate 6 is a major redesign of the world's most popular and feature-rich ORM solution. -The redesign has touched almost every subsystem of Hibernate, including the APIs, mapping annotations, and, above all else, the query language. - -This is the second time HQL has been completely reimplemented from scratch, but the first time in more than fifteen years. -In this new incarnation, HQL is far more powerful, and the HQL compiler much more robust. - -At long last, HQL has a feature set to match that of modern dialects of SQL, and is able to take full advantage of the power of modern SQL databases. - -This document is a reference guide to the full feature set of the language, and is the only up-to-date source for those who wish to learn how to write HQL effectively in Hibernate 6. - -But if you don't already know Hibernate, don't start here. -First, read _An introduction to Hibernate 6_, and then come back. +include::Preface.adoc[] <<< :numbered: -[[basic-concepts]] -== Basic concepts +include::Concepts.adoc[] -This document describes Hibernate Query Language (HQL), which is, in some sense, a dialect of the Java (now Jakarta) Persistence Query Language (JPQL). +<<< -Or is it the other way around? +include::Expressions.adoc[] -[NOTE] -==== -JPQL was inspired by early versions of HQL, and is a subset of modern HQL. -Here we focus on describing the complete, more powerful HQL language as it exists today. +<<< -If strict JPA compliance is what you're looking for, use the setting `hibernate.jpa.compliance.query=true`. -With this configuration, any attempt to use HQL features beyond the JPQL subset will result in an exception. +include::From.adoc[] -We don't recommend the use of this setting. -==== +<<< -The truth is that HQL today has capabilities that go far beyond what is possible in plain JPQL. -We're not going to fuss too much about not limiting ourselves to the standard here. -Faced with a choice between writing database-specific native SQL, or database-independent HQL, we know what our preference is. +include::Relational.adoc[] -[[hql-and-sqk]] -=== HQL and SQL - -Throughout this document, we'll assume you know SQL and the relational model, at least at a basic level. -HQL and JPQL are loosely based on SQL and are easy to learn for anyone familiar with SQL. - -For example, if you understand this SQL query: - -[source,sql] ----- -select book.title, pub.name -from Book as book - join Publisher as pub - on book.publisherId = pub.id -where book.title like 'Hibernate%' -order by book.title ----- - -Then we bet you can already make sense of this HQL: - -[source,sql] ----- -select book.title, pub.name -from Book as book - join book.publisher as pub -where book.title like 'Hibernate%' -order by book.title ----- - -You might notice that even for this very simple example, the HQL version is slightly shorter. -This is typical. -Actually, HQL queries are usually much more compact than the SQL they compile to. - -In this chapter, we'll demonstrate how similar HQL is to SQL by giving a quick overview of the basic statement types. -You'll be bored to discover they're exactly the ones you expect: `select`, `insert`, `update`, and `delete`. - -[WARNING] -==== -This is a reference guide. -We're not going to explain basic concepts like ternary logic, joins, aggregation, selection, or projection, because that information is freely available elsewhere, and anyway we couldn't possibly do these topics justice here. -If you don't have a firm grasp of these ideas, it's time to pick up a book about SQL or about the relational model. -==== - -But first we need to mention something that's a bit different to SQL. -HQL has a slightly complicated way of dealing with case sensitively. - -[[hql-case-sensitivity]] -=== Identifiers and case sensitivity - -An identifier is a name used to refer to an entity, an attribute of a Java class, an <>, or a function. - -For example, `Book`, `title`, `author`, and `upper` are all identifiers, but they refer to different kinds of things. -In HQL and JPQL, the case sensitivity of an identifier depends on the kind of thing the identifier refers to. - -The rules for case sensitivity are: - -- keywords and function names are case-insensitive, but -- identification variable names, Java class names, and the names of attributes of Java classes, are case-sensitive. - -We apologize for this inconsistency. -In hindsight, it might have been better to define the whole language as case-sensitive. - -[%unbreakable] -[NOTE] -==== -Incidentally, it's standard practice to use lowercase keywords in HQL and JPQL. - -The use of uppercase keywords indicates an endearing but unhealthy attachment to the culture of the 1970's. -==== - -Just to reiterate these rules: - -[cols="45,~"] -|=== -| `select`, `SeLeCT`, `sELEct`, and `SELECT` | All the same, `select` is a keyword -| `upper(name)` and `UPPER(name)` | Same, `upper` is a function name -| `from BackPack` and `from Backpack` | Different, refer to different Java classes -| `person.nickName` and `person.nickname` | Different, since the path expression element `nickName` refers to an attribute of an entity defined in Java -| `person.nickName`, `Person.nickName`, and `PERSON.nickName` | All different, since the first element of a path expression is an <> -|=== - -[CAUTION] -==== -The JPQL specification defines identification variables as case-_insensitive_. - -And so in strict JPA-compliant mode, Hibernate treats `person.nickName`, `Person.nickName`, and `PERSON.nickName` as the _same_. -==== - -A _quoted identifier_ is written in backticks. Quoting lets you use a keyword as an identifier, for example `` thing.\`select` ``. - -[[type-system]] -=== Type system - -JPA doesn't have a well-specified type system, but, reading between the lines a bit, the following types may be discerned: - -- entity types, -- numeric values, -- strings, -- dates/times, -- booleans, and -- enumerated types. - -Such a coarse-grained type system is in some sense an insufficient constraint on implementors of the specification, or, viewed from a different perspective, it leaves us quite a lot of flexibility. - -The way HQL interprets this type system is to assign a Java type to every expression in the language. -Thus, numeric expressions have types like `Long`, `Float`, or `BigInteger`, date/time expressions have types like `LocalDate`, `LocalDateTime`, or `Instant`, and boolean expressions are always of type `Boolean`. - -Going further, an expression like `local datetime - document.created` is assigned the Java type `java.time.Duration`, a type which doesn't appear anywhere in the JPA specification. - -Since the language must be executed on SQL databases, every type accommodates null values. - -[[null-values-and-ternary-logic]] -==== Null values and ternary logic - -The SQL `null` behaves quite differently to a null value in Java. -In Java, an expression like `number + 1` produces in an exception if `number` is null. -But in SQL, and therefore also in HQL and JPQL, such an expression evaluates to `null`. - -[IMPORTANT] -==== -It's almost always the case that an operation applied to a null value yields another null value. -This applies to function application, to operators like `*` and `||`, to comparison operators like `<` and `=`, and even to logical operations like `and` and `not`. - -The exceptions to this rule are the functions `coalesce()` and `ifnull()` which are specifically designed for <>. -==== - -This rule is the source of the famous (and controversial) _ternary logic_ of SQL. -A logical expression like `firstName='Gavin' and team='Hibernate'` isn't restricted to the values `true` and `false`. -It may also be `null`. - -This can in principle lead to some quite unintuitive results: we can't use the law of the excluded middle to reason about logical expressions in SQL! -But in practice, we've once never run into a case where this caused us problems. - -As you probably know, when a logical predicate occurs as a <>, rows for which the predicate evaluates to `null` are _excluded_ from the result set. -That is, in this context at least, a logical null is interpreted as "effectively false". - -[[hql-statement-types]] -=== Statement types - -HQL features four different kinds of statement: - -- `select` queries, -- `update` statements, -- `delete` statements, and -- `insert ... values` and `insert ... select` statements. - -Collectively, `insert`, `update`, and `delete` statements are sometimes called _mutation queries_. -We need to be a little bit careful when executing mutation queries via a stateful session. - -[IMPORTANT] -==== -The effect of an `update` or `delete` statement is not reflected in the persistence context, nor in the state of entity objects held in memory at the time the statement is executed. - -It's the responsibility of the client program to maintain synchronization of state held in memory with the database after execution of an `update` or `delete` statement. -==== - -Let's consider each type of mutation query in turn, beginning with the most useful type. - -[[hql-update]] -==== Update statements - -The https://en.wikipedia.org/wiki/Backus%E2%80%93Naur_Form[BNF] for an `update` statement is quite straightforward: - -[[hql-update-bnf-example]] -[source, antlrv4] ----- -include::{extrasdir}/statement_update_bnf.txt[] ----- - -The `set` clause has a list of assignments to attributes of the given entity. - -For example: - -[[hql-update-example]] -[source, hql] ----- -update Person set nickName = 'Nacho' where name = 'Ignacio' ----- - -Update statements are polymorphic, and affect mapped subclasses of the given entity class. -Therefore, a single HQL `update` statement might result in multiple SQL update statements executed against the database. - -An `update` statement must be executed using `Query.executeUpdate()`. - -[[hql-update-examples]] -[source, java] ----- -// JPA API -int updatedEntities = entityManager.createQuery( - "update Person p set p.name = :newName where p.name = :oldName") - .setParameter("oldName", oldName) - .setParameter("newName", newName) - .executeUpdate(); ----- -[source, java] ----- -// Hibernate native API -int updatedEntities = session.createMutationQuery( - "update Person set name = :newName where name = :oldName") - .setParameter("oldName", oldName) - .setParameter("newName", newName) - .executeUpdate(); ----- - -The integer value returned by `executeUpdate()` indicates the number of entity instances affected by the operation. - -[NOTE] -==== -In a `JOINED` inheritance hierarchy, multiple rows are required to store a single entity instance. -In this case, the update count returned by Hibernate might not be exactly the same as the number of rows affected in the database. -==== - -An `update` statement, by default, does not affect the column mapped by the `@Version` attribute of the affected entities. - -Adding the keyword `versioned`β€”writing `update versioned`β€”specifies that Hibernate should increment the version number or update the last modification timestamp. - -// [NOTE] -// ==== -// `update versioned` does not work with custom version types defined by implementing `UserVersionType`, and is not available in JPQL. -// ==== - -[[hql-update-versioned-example]] -[source, hql] ----- -update versioned Book set title = :newTitle where ssn = :ssn ----- - -Unfortunately, an `update` statement may not directly join other entities, not even using an <>, but it may have subqueries in its `set` clause, or in the `where` clause, which may contain joins. - -[[hql-delete]] -==== Delete statements - -The BNF for a `delete` statement is even simpler: - -[[hql-delete-bnf-example]] -[source, antlrv4] ----- -include::{extrasdir}/statement_delete_bnf.txt[] ----- - -For example: - -[source,hql] ----- -delete Author author where is empty author.books ----- - -As in SQL, the presence or absence of the `from` keyword has absolutely no effect on the semantics of the `update` statement. - -Just like update statements, delete statements are polymorphic, and affect mapped subclasses of the given entity class. -Therefore, a single HQL `delete` statement might result in multiple SQL delete statements executed against the database. - -A `delete` statement is executed by calling `Query.executeUpdate()`. - -The integer value returned by `executeUpdate()` indicates the number of entity instances affected by the operation. - -A `delete` statement may not directly join other entities, but it may have subqueries in the `where` clause, which may contain joins. - -[[hql-insert]] -==== Insert statements - -There are two kinds of `insert` statement: - -- `insert ... values`, where the attribute values to insert are given directly as tuples, and -- `insert ... select`, where the inserted attribute values are sourced from a subquery. - -The first form inserts a single row in the database, or multiple rows if you provide multiple tuples in the `values` clause. -The second form may insert many new rows, or none at all. - -[%unbreakable] -[TIP] -==== -The first sort of `insert` statement is not as useful. -It's usually better to just use `persist()`. - -On the other hand, you might consider using it to set up test data. -==== - -[NOTE] -==== -`insert` statements are not part of JPQL. -==== - -The BNF for an `insert` statement is: - -[[hql-insert-bnf-example]] -[source, antlrv4] ----- -include::{extrasdir}/statement_insert_bnf.txt[] ----- - -For example: - -[[hql-insert-example]] -[source, hql] ----- -insert Person (id, name) - values (100L, 'Jane Doe'), (200L, 'John Roe') ----- - -[source, hql] ----- -insert into Author (id, name, bio) - select id, name, name || ' is a newcomer for ' || str(year(local date)) - from Person - where id = :pid ----- - -As in SQL, the presence or absence of the `into` keyword has no effect on the semantics of the `insert` statement. - -From these examples we might notice that `insert` statements are in one respect a bit different to `update` and `delete` statements. - -[IMPORTANT] -==== -An `insert` statement is inherently _not_ polymorphic! -Its list of target fields is of fixed length, whereas each subclass of an entity class might declare additional fields. -If the entity is involved in a mapped inheritance hierarchy, only attributes declared directly by the named entity and its superclasses may occur in the list of target fields. -Attributes declared by subclasses may not occur. -==== - -The `queryExpression` in an `insert ... select` statement may be any valid `select` query, with the caveat that the types of the values in the `select` list must match the types of the target fields. - -[NOTE] -==== -This is checked during query compilation rather than allowing the type check to delegate to the database. -This may cause problems when two Java types map to the same database type. -For example, an attribute of type `LocalDateTime` and an attribute or type `Timestamp` both map to the SQL type `timestamp`, but are not considered assignable by the query compiler. -==== - -There are two ways to assign a value to the `@Id` attribute: - -- explicitly specify the id attribute in the list of target fields, and its value in the values assigned to the target fields, or -- omit it, in which case a generated value is used. - -Of course, the second option is only available for entities with database-level id generation (sequences or identity/autoincrement columns). -It's not available for entities whose id generator is implemented in Java, nor for entities whose id is assigned by the application. - -The same two options are available for a `@Version` attribute. -When no version is explicitly specified, the version for a new entity instance is used. - -Like `update` and `delete` statements, an `insert` statement must be executed by calling `Query.executeUpdate()`. - -Now it's time to look at something _much_ more complicated. - -[[hql-select]] -==== Select statements - -Select statements retrieve and analyse data. -This is what we're really here for. - -The full BNF for a `select` query is quite complicated, but there's no need to understand it now. -We're displaying it here for future reference. - -[[hql-select-bnf-example]] -[source, antlrv4] ----- -include::{extrasdir}/statement_select_bnf.txt[] ----- - -Most of the complexity here arises from the interplay of set operators (`union`, `intersect`, and `except`) with sorting. - -We'll describe the various clauses of a query later, in <> and in <>, but for now, to summarize, a query might have these bits: - -[cols="22,22,~"] -|=== -| Clause | Jargon | Purpose - -| `with` | Common table expressions | Declares <> to be used in the following query -| `from` and `join` | Roots and joins | <> the entities involved in the query, and how they're <> to each other -| `where` | Selection/restriction | Specifies a <> on the data returned by the query -| `group by`| Aggregation/grouping | Controls <> -| `having` | Selection/restriction | Specifies a <> to apply _after_ aggregation -| `select` | Projection | Specifies a <> (the things to return from the query) -| `union`, `intersect`, `except` | Set algebra | These are <> applied to the results of multiple subqueries -| `order by` | Ordering | Specifies how the results should be <> -| `limit`, `offset`, `fetch` | Limits | Allows for <> the results -|=== - -Every one of these clauses is optional! - -For example, the simplest query in HQL has no `select` clause at all: - -[[hql-select-simplest-example]] -[source, hql] ----- -from Book ----- - -But we don't necessarily _recommend_ leaving off the `select` list. - -[NOTE] -==== -HQL doesn't require a `select` clause, but JPQL _does_. -==== - -Naturally, the previous query may be written with a `select` clause: - -[source, hql] ----- -select book from Book book ----- - -But when there's no explicit `select` clause, the select list is implied by the result type of the query: - -[source, java] -[%unbreakable] ----- -// result type Book, only the Book selected -List books = - session.createQuery("from Book join authors", Book.class) - .getResultList(); -for (Person person: persons) { - ... -} ----- - -[source, java] -[%unbreakable] ----- -// result type Object[], both Book and Author selected -List booksWithAuthors = - session.createQuery("from Book join authors", Book.class, Object[].class) - .getResultList(); -for (var bookWithAuthor: booksWithAuthors) { - Book book = (Book) bookWithAuthor[0]; - Author author = (Author) bookWithAuthor[1]; - ... -} ----- - -For complicated queries, it's probably best to explicitly specify a `select` list. - -An alternative "simplest" query has _only_ a `select` list: - -[[hql-select-simplest-example-alt]] -[source, hql] ----- -select local datetime ----- - -This results in a SQL `from dual` query (or equivalent). - -[TIP] -==== -Looking carefully at the BNF given above, you might notice that the `select` list may occur either at the beginning of a query, or near the end, right before `order by`. - -Of course, standard SQL, and JPQL, require that the `select` list comes at the beginning. -But it's more natural to put it last: - -[source, hql] ----- -from Book book select book.title, book.isbn ----- - -This form of the query is more readable, because the alias is declared _before_ it's used, just as God and nature intended. -==== - -Of course, queries are always polymorphic. -Indeed, a fairly innocent-looking HQL query can easily translate to a SQL statement with many joins and unions. - -[TIP] -==== -We need to be a _bit_ careful about that, but actually it's usually a good thing. -HQL makes it very easy to fetch all the data we need in a single trip to the database, and that's absolutely key to achieving high performance in data access code. -Typically, it's much worse to fetch exactly the data we need, but in many round trips to the database server, than it is to fetch just a bit more data than what we're going to need, all a single SQL query. -==== - -[[hql-expressions]] -== Expressions - -We now switch gears, and begin describing the language from the bottom up. -The very bottom of a programming language is its syntax for literal values. - -// Essentially, expressions are references that resolve to basic or tuple values. - -[[hql-literals]] -=== Literals - -The most important literal value in this language is `null`. It's assignable to any other type. - -[[hql-boolean-literals]] -==== Boolean literals - -The boolean literal values are the (case-insensitive) keywords `true` and `false`. - -[[hql-string-literals]] -==== String literals - -String literals are enclosed in single quotes. - -[source,hql] ----- -select 'hello world' ----- - -To escape a single quote within a string literal, use a doubled single quote: `''`. - -[[hql-string-literals-example]] -//.String literals examples -[source, hql] ----- -from Book where title like 'Ender''s' ----- - -Alternatively, Java-style double-quoted strings are also allowed, with the usual Java character escape syntax. - -[source,hql] ----- -select "hello\tworld" ----- - -This option is not much used. - -[[hql-numeric-literals]] -==== Numeric literals - -Numeric literals come in several different forms: - -|=== -| Kind | Type | Example - -| Integer literals | `Long`, `Integer`, `BigInteger` | `1`, `3_000_000L`, `2BI` -| Decimal literals | `Double`, `Float`, `BigDecimal` | `1.0`, `123.456F`, `3.14159265BD` -| Hexadecimal literals | `Long`, `Integer` | `0X1A2B`, `0x1a2b` -| Scientific notation | `Double`, `Float`, `BigDecimal` | `1e-6`, `6.674E-11F` -|=== - -For example: - -[[hql-numeric-literals-example]] -[source, hql] ----- -from Book where price < 100.0 ----- -[source, hql] ----- -select author, count(book) -from Author as author - join author.books as book -group by author -having count(book) > 10 ----- - -The type of a numeric literal may be specified using a Java-style postfix: -|=== -| Postfix | Type | Java type - -| `L` or `l` | long integer | `long` -| `D` or `d` | double precision | `double` -| `F` or `f` | single precision | `float` -| `BI` or `bi` | large integer | `BigInteger` -| `BD` or `bd` | exact decimal | `BigDecimal` -|=== - -It's not usually necessary to specify the precision explicitly. - -[NOTE] -==== -In a literal with an exponent, the `E` is case-insensitive. -Similarly, the Java-style postfix is case-insensitive. -==== - -[[hql-datetime-literals]] -==== Date and time literals - -According to the JPQL specification, date and time literals may be specified using the JDBC escape syntax. -Since this syntax is rather unpleasant to look at, HQL provides not one, but two alternatives. - -|=== -| Date/time type | Recommended Java type | JDBC escape syntax πŸ’€| Braced literal syntax | Explicitly typed literal syntax - -| Date | `LocalDate` | `{d 'yyyy-mm-dd'}` | `{yyyy-mm-dd}` | `date yyyy-mm-dd` -| Time | `LocalTime` | `{t 'hh:mm'}` | `{hh:mm}` | `time hh:mm` -| Time with seconds | `LocalTime` | `{t 'hh:mm:ss'}` | `{hh:mm:ss}` | `time hh:mm:ss` -| Datetime | `LocalDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss'}` | `{yyyy-mm-dd hh:mm:ss}` | `datetime yyyy-mm-dd hh:mm:ss` -| Datetime with milliseconds | `LocalDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss.millis'}` | `{yyyy-mm-dd hh:mm:ss.millis}` | `datetime yyyy-mm-dd hh:mm:ss.millis` -| Datetime with an offset | `OffsetDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss+hh:mm'}` | `{yyyy-mm-dd hh:mm:ss +hh:mm}` | `datetime yyyy-mm-dd hh:mm:ss +hh:mm` -| Datetime with a time zone | `OffsetDateTime` | `{ts 'yyyy-mm-ddThh:mm:ss GMT'}` | `{yyyy-mm-dd hh:mm:ss GMT}` | `datetime yyyy-mm-dd hh:mm:ss GMT` -|=== - -Literals referring to the current date and time are also provided. -Again there is some flexibility. - -|=== -| Date/time type | Java type | Underscored syntax | Spaced syntax - -| Date | `java.time.LocalDate` | `local_date` | `local date` -| Time | `java.time.LocalTime` | `local_time` | `local time` -| Datetime | `java.time.LocalDateTime` | `local_datetime` | `local datetime` -| Offset datetime | `java.time.OffsetDateTime`| `offset_datetime` | `offset datetime` -| Instant | `java.time.Instant` | `instant` | `instant` -| Date | `java.sql.Date` πŸ’€| `current_date` | `current date` -| Time | `java.sql.Time` πŸ’€| `current_time` | `current time` -| Datetime | `java.sql.Timestamp` πŸ’€| `current_timestamp` | `current timestamp` -|=== - -Of these, only `local date`, `local time`, `local datetime`, `current_date`, `current_time`, and `current_timestamp` are defined by the JPQL specification. - -[IMPORTANT] -==== -The use of date and time types from the `java.sql` package is strongly discouraged! -Always use `java.time` types in new code. -==== - -[[hql-duration-literals]] -==== Duration literals - -There are two sorts of duration in HQL: - -* _year-day durations_, that is, the length of an interval between two dates, and -* _week-nanosecond durations_, that is, the length of an interval between two datetimes. - -For conceptual reasons, the two kinds of duration cannot be cleanly composed. - -Literal duration expressions are of form `n unit`, for example `1 day` or `10 year` or `100 nanosecond`. - -The unit may be: `day`, `month`, `quarter`, `year`, `second`, `minute`, `hour`, or `nanosecond`. - -[NOTE] -==== -A HQL duration is considered to map to a Java `java.time.Duration`, but semantically they're perhaps more similar to an ANSI SQL `INTERVAL` type. -==== - -[[hql-binary-literals]] -==== Binary string literals - -HQL also provides a choice of formats for binary strings: - -* the braced syntax `{0xDE, 0xAD, 0xBE, 0xEF}`, a list of Java-style hexadecimal byte literals, or -* the quoted syntax `X'DEADBEEF'` or `x'deadbeef'`, similar to SQL. - -[[hql-enum-literals]] -==== Enum literals - -Literal values of a Java enumerated type may be written without needing to specify the enum class name: - -[[hql-enum-example]] -[source, hql] ----- -from Book where status <> OUT_OF_PRINT ----- - -Here, the enum class is inferred from the type of the expression on the left of the comparison operator. - -[[hql-java-constants]] -==== Java constants - -HQL allows any Java `static` constant to be used in HQL, but it must be referenced by its fully-qualified name: - -[[hql-java-constant-example]] -[source, hql] ----- -select java.lang.Math.PI ----- - -[[hql-entity-name-literals]] -==== Literal entity names - -Entity names may also occur as a literal value. They do not need to be qualified. - -[source,hql] ----- -from Payment as payment -where type(payment) = CreditCardPayment ----- - -See <>. - -[[hql-path-expressions]] -=== Identification variables and path expressions - -Identification variables, and path expressions beginning with an identification variable are legal expressions in almost every context. - -[source,hql] ----- -select book.publisher.name from Book book ----- - -See <> and <>. - -=== Operator expressions - -HQL has operators for working with strings, numeric values, and date/time types. - -[[hql-concatenation]] -==== String concatenation - -HQL defines two ways to concatenate strings: - -* the SQL-style concatenation operator, `||`, and -* the JPQL-standard `concat()` function. - -See <> for details of the `concat()` function. - -[[hql-concatenation-example]] -[source, hql] ----- -select book.title || ' by ' || listagg(author.name, ' & ') -from Book as book - join book.authors as author -group by book ----- - -Many more operations on strings are defined below, in <>. - -[[hql-numeric-arithmetic]] -==== Numeric arithmetic - -The basic SQL arithmetic operators, `+`,`-`,`*`, and `/` are joined by the remainder operator `%`. - -[[hql-numeric-arithmetic-example]] -[source, hql] ----- -select (1.0 + :taxRate) * sum(item.book.price * item.quantity) -from Order as ord - join ord.items as item -where ord.id = :oid ----- - -When both operands of a binary numeric operator have the same type, the result type of the whole expression is the same as the operands. - -[WARNING] -==== -Thus, `3/2` performs integer division and evaluates to `1`. -==== - -When the operands are of different type, one of the operands is implicitly converted to _wider_ type, with wideness given, in decreasing order, by the list below: - -- `Double` (widest) -- `Float` -- `BigDecimal` -- `BigInteger` -- `Long` -- `Integer` -- `Short` -- `Byte` - -Many more numeric operations are defined below, in <>. - -[[hql-Datetime-arithmetic]] -==== Datetime arithmetic - -Arithmetic involving dates, datetimes, and durations is quite subtle. -Among the issues to consider are: - -- There's two kinds of duration: year-day, and week-nanosecond durations. - The first is a difference between dates; the second is a difference between datetimes. -- We can subtract dates and datetimes, but we can't add them. -- A Java-style duration has much too much precision, and so in order to use it for anything useful, we must somehow truncate it to something coarser-grained. - -Here we list the basic operations. - -[cols="10,38,~,18"] -|=== -| Operator | Expression type | Example | Resulting type - -| `-` | Difference between two dates | `your.birthday - local date` | year-day duration -| `-` | Difference between two datetimes | `local datetime - record.lastUpdated` | week-nanosecond duration -| `+` | Sum of a date and a year-day duration | `local date + 1 week` | date -| `+` | Sum of a datetime and a week-nanosecond duration | `record.lastUpdated + 1 second` | datetime -| `*` | Product of an integer and a duration | `billing.cycles * 30 day` | duration -| `by unit` | Convert a duration to an integer | `(1 year) by day` | integer -|=== - -The `by unit` operator converts a duration to an integer, for example: `(local date - your.birthday) by day` evaluates to the number of days you still have to wait. - -The function `extract(unit from ...)` extracts a field from a date, time, or datetime type, for example, `extract(year from your.birthday)` produces the year in which you were born, and throws away important information about your birthday. - -[IMPORTANT] -==== -Please carefully note the difference between these two operations: `by` and `extract()` both evaluate to an integer, but they have very different uses. -==== - -Additional datetime operations, including the useful `format()` function, are defined below, in <>. - -[[hql-case-expressions]] -=== Case expressions - -Just like in standard SQL, there are two forms of case expression: - -* the _simple_ case expression, and -* the so-called _searched_ case expression. - -[TIP] -==== -Case expressions are verbose. -It's often simpler to use the `coalesce()`, `nullif()`, or `ifnull()` functions, -as described below in <>. -==== - -[[hql-simple-case-expressions]] -===== Simple case expressions - -The syntax of the simple form is defined by: - -[[hql-simple-case-expressions-bnf]] -[source, antlrv4] ----- -include::{extrasdir}/simple_case_bnf.txt[] ----- - -For example: - -[[hql-simple-case-expressions-example]] -[source, hql] ----- -select - case author.nomDePlume - when '' then person.name - else author.nomDePlume end -from Author as author - join author.person as person ----- - -[[hql-searched-case-expressions]] -===== Searched case expressions - -The searched form has the following syntax: - -[[hql-searched-case-expressions-bnf]] -[source, antlrv4] ----- -include::{extrasdir}/searched_case_bnf.txt[] ----- - -For example: - -[[hql-searched-case-expressions-example]] -[source, hql] ----- -select - case - when author.nomDePlume is null then person.name - else author.nomDePlume end -from Author as author - join author.person as person ----- - -A `case` expression may contain complex expression, including operator expressions. - -[[hql-exp-functions]] -=== Functions - -Both HQL and JPQL define some standard functions and make them portable between databases. - -[%unbreakable] -[TIP] -==== -A program that wishes to remain portable between Jakarta Persistence providers should in principle limit itself to the use of the functions which are blessed by the specification. -Unfortunately, there's not so many of them. -==== - -In some cases, the syntax of these functions looks a bit funny at first, for example, `cast(number as String)`, or `extract(year from date)`, or even `trim(leading '.' from string)`. -This syntax is inspired by standard ANSI SQL, and we promise you'll get used to it. - -[%unbreakable] -[IMPORTANT] -==== -HQL abstracts away from the actual database-native SQL functions, letting you write queries which are portable between databases. - -For some functions, and always depending on the database, a HQL function invocation translates to a quite complicated SQL expression! -==== - -In addition, there are several ways to use a database function that's not known to Hibernate. - -[[hql-functions-typecasts]] -==== Types and typecasts - -The following special functions make it possible to discover or narrow expression types: - -[cols="15,~,~,^15"] -|=== -| Special function | Purpose | Signature | JPA standard - -| `type()` | The (concrete) entity name | `type(e)` | βœ” -| `treat()` | Narrow an entity type | `treat(e as Entity)` | βœ” -| `cast()` | Narrow a basic type | `cast(x as Type)` | βœ– -| `str()` | Cast to a string | `str(x)` | βœ– -|=== - -Let's see what these functions do. - -[[hql-function-type]] -[discrete] -===== Evaluating an entity type: `type()` - -The function `type()`, applied to an identification variable, evaluates to the entity name of the referenced entity. -This is mainly useful when dealing with entity inheritance hierarchies. - -[[hql-entity-type-exp-example]] -[source, hql] ----- -select payment -from Payment as payment -where type(payment) = CreditCardPayment ----- - -[[hql-function-treat]] -[discrete] -===== Narrowing an entity type: `treat()` - -The function `treat()` may be used to narrow the type of an identification variable. -This is useful when dealing with entity inheritance hierarchies. - -[[hql-treat-example]] -[source, hql] ----- -select payment -from Payment as payment -where length(treat(payment as CreditCardPayment).cardNumber) - between 16 and 20 ----- - -The type of the expression `treat(p as CreditCardPayment)` is the narrowed type, `CreditCardPayment`, instead of the declared type `Payment` of `p`. -This allows the attribute `cardNumber` declared by the subtype `CreditCardPayment` to be referenced. - -The `treat()` function may even occur in a <>. - -[[hql-function-cast]] -[discrete] -===== General typecasts: `cast()` - -The function `cast()` has a similar syntax, but is used to narrow basic types. -Its first argument is usually an attribute of an entity, or a more complex expression involving entity attributes. - -The target type is an unqualified Java class name: -`String`, `Long`, `Integer`, `Double`, `Float`, `Character`, `Byte`, `BigInteger`, `BigDecimal`, `LocalDate`, `LocalTime`, `LocalDateTime`, etc. - -[source, hql] ----- -select cast(id as String) from Order ----- - -[[hql-function-str]] -[discrete] -===== Casting to string: `str()` - -The function `str(x)` is a synonym for `cast(x as String)`. - -[source, hql] ----- -select str(id) from Order ----- - -[[hql-functions-null]] -==== Functions for working with null values - -The following functions make it easy to deal with null values: - -[cols="15,~,~,^15"] -|=== -| Function | Purpose | Signature | JPA standard - -| `coalesce()` | First non-null argument | `coalesce(x, y, z)` | βœ” -| `ifnull()` | Second argument if first is null | `ifnull(x,y)` | βœ– -| `nullif()` | `null` if arguments are equal | `nullif(x,y)` | βœ” -|=== - -[discrete] -===== Handling null values: `coalesce()` - -An abbreviated `case` expression that returns the first non-null operand. - -[[hql-coalesce-example]] -[source, hql] ----- -select coalesce(author.nomDePlume, person.name) -from Author as author - join author.person as person ----- - -[discrete] -===== Handling null values: `ifnull()` - -HQL allows `ifnull()` as a synonym for `coalesce()` in the case of exactly two arguments. - -[[hql-ifnull-example]] -[source, hql] ----- -select ifnull(author.nomDePlume, person.name) -from Author as author - join author.person as person ----- - -[discrete] -===== Producing null values: `nullif()` - -Evaluates to null if its operands are equal, or to its first argument otherwise. - -[[hql-nullif-example]] -[source, hql] ----- -select ifnull(nullif(author.nomDePlume, person.name), 'Real name') -from Author as author - join author.person as person ----- - -[[hql-functions-datetime]] -==== Functions for working with dates and times - -There are some very important functions for working with dates and times. - -[cols="15,~,~,^15"] -|=== -| Special function | Purpose | Signature | JPA standard - -| `extract()` | Extract a datetime field | `extract(field from x)` | βœ” -| `format()` | Format a datetime as a string | `format(datetime as pattern)` | βœ– -| `trunc()` or `truncate()` | Datetime truncation | `truncate(datetime, field)` | βœ– -|=== - -[[hql-function-extract]] -[discrete] -===== Extracting date and time fields: `extract()` - -The special function `extract()` obtains a single field of a date, time, or datetime. - -Field types include: `day`, `month`, `year`, `second`, `minute`, `hour`, `day of week`, `day of month`, `week of year`, `date`, `time`, `epoch` and more. -For a full list of field types, see the Javadoc for https://docs.jboss.org/hibernate/orm/{majorMinorVersion}/javadocs/org/hibernate/query/TemporalUnit.html[`TemporalUnit`]. - -[source, hql] ----- -from Order where extract(date from created) = local date ----- -[source, hql] ----- -select extract(year from created), extract(month from created) from Order ----- - -The following functions are abbreviations for `extract()`: - -[cols="15,~,^15"] -|=== -| Function | Long form using `extract()` | JPA standard - -| `year(x)` | `extract(year from x)` | βœ– -| `month(x)` | `extract(month from x)` | βœ– -| `day(x)` | `extract(day from x)` | βœ– -| `hour(x)` | `extract(year from x)` | βœ– -| `minute(x)` | `extract(year from x)` | βœ– -| `second(x)` | `extract(year from x)` | βœ– -|=== - -TIP: These abbreviations aren't part of the JPQL standard, but on the other hand they're a lot less verbose. - -[source, hql] ----- -select year(created), month(created) from Order ----- - -[[hql-function-format]] -[discrete] -===== Formatting dates and times: `format()` - -This function formats a date, time, or datetime according to a pattern. - -The syntax is `format(datetime as pattern)`, and the pattern must be written in a subset of the pattern language defined by Java's `java.time.format.DateTimeFormatter`. - -For a full list of `format()` pattern elements, see the Javadoc for https://docs.jboss.org/hibernate/orm/{majorMinorVersion}/javadocs/org/hibernate/dialect/Dialect.html#appendDatetimeFormat[`Dialect.appendDatetimeFormat`]. - -[[hql-function-trunc-datetime]] -[discrete] -===== Truncating a date or time type: `trunc()` or `truncate()` - -This function truncates a date, time, or datetime to the temporal unit specified by field. - -The syntax is `truncate(datetime, field)`. Supported temporal units are: `year`, `month`, `day`, `hour`, `minute` or `second`. - -Truncating a date, time or datetime value translates to obtaining a value of the same type in which all temporal units smaller than `field` have been pruned. -For hours, minutes and second this means setting them to `00`. For months and days, this means setting them to `01`. - -[[hql-string-functions]] -==== Functions for working with strings - -Naturally, there are a good number of functions for working with strings. - -[cols="15,~,~,^15"] -|=== -| Function | Purpose | Syntax | JPA standard / ANSI SQL Standard - -| `upper()` | The string, with lowercase characters converted to uppercase | `upper(s)` | βœ” / βœ” -| `lower()` | The string, with uppercase characters converted to lowercase | `lower(s)` | βœ” / βœ” -| `length()` | The length of the string | `length(s)` | βœ” / βœ– -| `concat()` | Concatenate strings | `concat(x, y, z)` | βœ” / βœ– -| `locate()` | Location of string within a string | `locate(s, d)`, + -`locate(s, d, i)` | βœ” / βœ– -| `position()` | Similar to `locate()` | `position(pattern in string)` | βœ– / βœ” -| `substring()` | Substring of a string (JPQL-style) | `substring(s, i)`, + -`substring(s, i, l)` | βœ” / βœ– -| `substring()` | Substring of a string (ANSI SQL-style) -| `substring(string from start)`, + -`substring(string from start for length)` | βœ– / βœ” -| `trim()` | Trim characters from string | See below | βœ” / βœ” -| `overlay()` | For replacing a substring -| `overlay(string placing replacement from start)`, + -`overlay(string placing replacement from start for length)` | βœ– / βœ” -| `pad()` | Pads a string with whitespace, or with a specified character -| `pad(string with length)`, + -`pad(string with length leading)`, + -`pad(string with length trailing)`, or + -`pad(string with length leading character)` | βœ– / βœ– -| `left()` | The leftmost characters of a string | `left(string, length)` | βœ– / βœ– -| `right()` | The rightmost characters of a string | `right(string, length)` | βœ– / βœ– -| `replace()` | Replace every occurrence of a pattern in a string | `replace(string, pattern, replacement)` | βœ– / βœ– -| `repeat()` | Concatenate a string with itself multiple times | `replace(string, times)` | βœ– / βœ– -| `collate()` | Select a collation | `collate(p.name as collation)` | βœ– / βœ– -|=== - -Let's take a closer look at just some of these. - -[IMPORTANT] -==== -Contrary to Java, positions of characters within strings are indexed from 1 instead of 0! -==== - -[discrete] -===== Concatenating strings: `concat()` - -Accepts a variable number of arguments, and produces a string by concatenating them. - -[source, hql] ----- -select concat(book.title, ' by ', listagg(author.name, ' & ')) -from Book as book - join book.authors as author -group by book ----- - -[discrete] -===== Finding substrings: `locate()` -The JPQL function `locate()` determines the position of a substring within another string. - -- The optional third argument is used to specify a position at which to start the search. - -[source, hql] ----- -select locate('Hibernate', title) from Book ----- - -[discrete] -===== Finding substrings: `position()` - -The `position()` function has a similar purpose, but follows the ANSI SQL syntax. - -[source, hql] ----- -select position('Hibernate' in title) from Book ----- - -[discrete] -===== Slicing strings: `substring()` -Returns a substring of the given string. - -- The second argument specifies the position of the first character of the substring. -- The optional third argument specifies the maximum length of the substring. - -[source, hql] ----- -select substring(title, 0, position(' for Dummies')) from Book ----- - -[discrete] -===== Trimming strings: `trim()` -The `trim()` function follows the syntax and semantics of ANSI SQL. -It may be used to trim `leading` characters, `trailing` characters, or both. - -[source, hql] ----- -select trim(title) from Book ----- -[source, hql] ----- -select trim(trailing ' ' from text) from Book ----- - -Its BNF is funky: - -[source, antlrv4] ----- -trimFunction - : "TRIM" "(" trimSpecification? trimCharacter? "FROM"? expression ")" ; -trimSpecification - : "LEADING" | "TRAILING" | "BOTH" ; ----- - -[discrete] -===== Collations: `collate()` - -Selects a collation to be used for its string-valued argument. -Collations are useful for <> with `<` or `>`, and in the <>. - -For example, `collate(p.name as ucs_basic)` specifies the SQL standard collation `ucs_basic`. - -IMPORTANT: Collations aren't very portable between databases. - -[[hql-functions-numeric]] -==== Numeric functions - -Of course, we also have a number of functions for working with numeric values. - -[cols="15,~,~,^15"] -|=== -| Function | Purpose | Signature | JPA standard - -| `abs()` | The magnitude of a number | `abs(x)` | βœ” -| `sign()` | The sign of a number | `sign(x)` | βœ” -| `mod()` | Remainder of integer division | `mod(n,d)` | βœ” -| `sqrt()` | Square root of a number | `sqrt(x)` | βœ” -| `exp()` | Exponential function | `exp(x)` | βœ” -| `power()` | Exponentiation | `power(x,y)` | βœ” -| `ln()` | Natural logarithm | `ln(x)` | βœ” -| `round()` | Numeric rounding | `round(number)`, + -`round(number, places)` | βœ” -| `trunc()` or `truncate()` | Numeric truncation | `truncate(number)`, + -`truncate(number, places)` | βœ– -| `floor()` | Floor function | `floor(x)` | βœ” -| `ceiling()` | Ceiling function | `ceiling(x)` | βœ” - -| `log10()` | Base-10 logarithm | `log10(x)` | βœ– -| `log()` | Arbitrary-base logarithm | `log(b,x)` | βœ– -| `pi` | π | `pi` | βœ– -| `sin()`, `cos()`, `tan()`, `asin()`, `acos()`, `atan()` -| Basic trigonometric functions | `sin(theta)`, `cos(theta)` | βœ– -| `atan2()` | Two-argument arctangent (range `(-π,π]`) | `atan2(y, x)` | βœ– -| `sinh()`, `cosh()`, `tanh()` | Hyperbolic functions | `sinh(x)`, `cosh(x)`, `tanh(x)` | βœ– -| `degrees()` | Convert radians to degrees | `degrees(x)` | βœ– -| `radians()` | Convert degrees to radians | `radians(x)` | βœ– -| `least()` | Return the smallest of the given arguments | `least(x, y, z)` |βœ– -| `greatest()` | Return the largest of the given arguments | `greatest(x, y, z)` | βœ– -|=== - -We haven't included <>, <>, or <> -in this list, because their purpose is more specialized, and because they come with extra special syntax. - -[[hql-functions-collections]] -==== Functions for dealing with collections - -The following functions apply to any identification variable that refers to a joined collection or many-valued association. - -[[hql-collection-functions]] -[cols="12,20,~,^15"] -|=== -| Function | Applies to | Purpose | JPA standard - -| `size()` | Any collection | The size of a collection | βœ– -| `element()` | Any collection | The element of a list | βœ– -| `index()`| Lists | The index of a list element | βœ– -| `key()`| Maps | The key of a map entry | βœ– -| `value()`| Maps | The value of a map entry | βœ– -| `entry()`| Maps | The whole entry in a map | βœ– -|=== - -[discrete] -===== Collection sizes: `size()` - -The number of elements of a collection or to-many association. - -[[hql-size-example]] -[source, hql] ----- -select name, size(books) from Author ----- - -[[hql-list-functions]] -[discrete] -===== List elements and indexes: `element()` and `index()` - -A reference to an element or index of <>. - -[[hql-map-functions]] -[discrete] -===== Map keys, values, and entries: `key()`, `value()`, and `entry()` - -A reference to a key, value, or entry of a <>. - -[[hql-elements-indices]] -==== Quantification over collections - -There's two additional functions of collections which we didn't include in previous table because they're much less-used and a bit harder to understand. - -[cols="12,30,~"] -|=== -| HQL Function | Applies to | Purpose - -| `elements()` | Any collection | Refers to the elements of a collection as a whole - -| `indices()` | Indexed collections (lists and maps) | Similar to `elements()` but refers to the collections indices (keys/positions) as a whole -|=== - -The `elements()` and `indices()` functions give us a shortcut way to write a subquery: -We may use these functions with: - -- an <> or <> predicate, -- a <>, or -- an <>. - -[cols="35,~"] -|=== -| Shortcut | Equivalent subquery - -| `exists elements(book.editions)` | `exists (select ed from book.editions as ed)` -| `2 in indices(book.editions)` | `2 in (select index(ed) from book.editions as ed)` -| `10 > all(elements(book.printings))` | `10 > all(select pr from book.printings as pr)` -| `max(elements(book.printings))` | `(select max(pr) from book.printings as pr)` -|=== - -These functions are most useful with ``@ElementCollection``s. - -[[hql-functions-model]] -==== Functions for working with ids and versions - -Finally, the following functions evaluate the id, version, or natural id of an entity, or the foreign key of a to-one association: - -[[hql-model-functions]] -[cols="12,~,^15"] -|=== -| Function | Purpose | JPA standard - -| `id()` | The value of the entity `@Id` attribute. | βœ– -| `version()` | The value of the entity `@Version` attribute. | βœ– -| `naturalid()` | The value of the entity `@NaturalId` attribute. | βœ– -| `fk()` | The value of the foreign key column mapped by a `@ManyToOne` (or logical `@OneToOne`) association. -Useful with associations annotated `@NotFound`. | βœ– -|=== - -[[hql-user-defined-functions]] -==== Native and user-defined functions - -The functions we've described above are the functions abstracted by HQL and made portable across databases. -But, of course, HQL can't abstract every function in your database. - -There are several ways to call native or user-defined SQL functions. - -- A native or user-defined function may be called using JPQL's `function` syntax, for example, ``function('sinh', phi)``. - (This is the easiest way, but not the best way.) -- A user-written `FunctionContributor` may register user-defined functions. -- A custom `Dialect` may register additional native functions by overriding `initializeFunctionRegistry()`. - -[TIP] -==== -Registering a function isn't hard, but is beyond the scope of this chapter. - -(It's even possible to use the APIs Hibernate provides to make your own _portable_ functions!) -==== - -Fortunately, every built-in `Dialect` already registers many native functions for the database it supports. - -[TIP] -==== -Try setting the log category `org.hibernate.HQL_FUNCTIONS` to debug. -Then at startup Hibernate will log a list of type signatures of all registered functions. -==== - - -[[hql-function-sql]] -==== Embedding native SQL in HQL - -The special function `sql()` allows the use of native SQL fragments inside an HQL query. - -The signature of this function is `sql(pattern[, argN]*)`, where `pattern` must be a string literal but the remaining arguments may be of any type. -The pattern literal is unquoted and embedded in the generated SQL. -Occurrences of `?` in the pattern are replaced with the remaining arguments of the function. - -We may use this, for example, to perform a native PostgreSQL typecast: -[source, hql] ----- -from Computer c where c.ipAddress = sql('?::inet', '127.0.0.1') ----- -This results in SQL logically equivalent to: -[source, sql] ----- -select * from Computer c where c.ipAddress = '127.0.0.1'::inet ----- -Or we can use a native SQL operator: -[source, hql] ----- -from Human h order by sql('(? <-> ?)', h.workLocation, h.homeLocation) ----- -And this time the SQL is logically equivalent to: -[source, sql] ----- -select * from Human h where (h.workLocation <-> h.homeLocation) ----- - -[[hql-conditional-expressions]] -=== Predicates - -A predicate is an operator which, when applied to some argument, evaluates to `true` or `false`. -In the world of SQL-style ternary logic, we must expand this definition to encompass the possibility that the predicate evaluates to `null`. -Typically, a predicate evaluates to `null` when one of its arguments is `null`. - -Predicates occur in the `where` clause, the `having` clause and in searched case expressions. - -[[hql-relational-comparisons]] -==== Comparison operators - -The binary comparison operators are borrowed from SQL: `=`, `>`, `>=`, `<`, `\<=`, `<>`. - -TIP: If you prefer, HQL treats `!=` as a synonym for `<>`. - -The operands should be of the same type. - -[[hql-relational-comparisons-example]] -[source, hql] ----- -from Book where price < 1.0 ----- -[source, hql] ----- -from Author as author where author.nomDePlume <> author.person.name ----- -[source, hql] ----- -select id, total -from ( - select ord.id as id, sum(item.book.price * item.quantity) as total - from Order as ord - join Item as item - group by ord -) -where total > 100.0 ----- - -[[hql-between-predicate]] -==== `between` predicate - -The ternary `between` operator, and its negation, `not between`, determine if a value falls within a range. - -Of course, all three operands must be of compatible type. - -[[hql-between-predicate-example]] -[source, hql] ----- -from Book where price between 1.0 and 100.0 ----- - -[[hql-null-predicate]] -==== Operators for dealing with null - -The following operators make it easier to deal with null values. - -[cols="20,20,15,~"] -|=== -| Operator | Negation | Type | Semantics - -| `is null` | `is not null` | Unary postfix | `true` if the value to the left is null -| `is distinct from` | `is not distinct from` | Binary | `true` if the value on the left is equal to the value on the right, or if both are null -|=== - -[[hql-null-predicate-example]] -[source, hql] ----- -from Author where nomDePlume is not null ----- - -[[hql-like-predicate]] -==== String pattern matching - -The `like` operator performs pattern matching on strings. -Its friend `ilike` performs case-insensitive matching. - -Their syntax is defined by: - -[[hql-like-predicate-bnf]] -[source, antlrv4] ----- -include::{extrasdir}/predicate_like_bnf.txt[] ----- - -The expression on the right is a pattern, where: - -* `_` matches any single character, -* `%` matches any number of characters, and -* if an escape character is specified, it may be used to escape either of these wildcards. - -[[hql-like-predicate-example]] -[source, hql] ----- -from Book where title not like '% for Dummies' ----- - -The optional `escape` character allows a pattern to include a literal `_` or `%` character. - -As you can guess, `not like` and `not ilike` are the enemies of `like` and `ilike`, and evaluate to the exact opposite boolean values. - -[[hql-in-predicate]] -==== `in` predicate - -The `in` predicates evaluates to true if the value to its left is in ... well, whatever it finds to its right. - -Its syntax is unexpectedly complicated: - -[[hql-in-predicate-bnf]] -[source, antlrv4, indent=0] ----- -include::{extrasdir}/predicate_in_bnf.txt[] ----- - -This less-than-lovely fragment of the HQL ANTLR grammar tells us that the thing to the right might be: - -- a list of values enclosed in parentheses, -- a subquery, -- one of the functions `elements()` or `indices()` defined <>, or -- a query parameter, - -The type of the expression on the left, and the types of all the values on the right must be compatible. - -[%unbreakable] -[NOTE] -==== -JPQL limits the legal types to string, numeric, date/time, and enum types, and in JPQL the left expression must be either: - -- a _state field_, which means a basic attribute, excluding associations and embedded attributes, or -- an <>. - -HQL is far more permissive. HQL itself does not restrict the type in any way, though the database itself might. -Even embedded attributes are allowed, although that feature depends on the level of support for tuple or "row value" constructors in the underlying database. -==== - -[[hql-in-predicate-example]] -[source, hql] ----- -from Payment as payment -where type(payment) in (CreditCardPayment, WireTransferPayment) ----- -[source, hql] ----- -from Author as author -where author.person.name in (select name from OldAuthorData) ----- - -This example doesn't work on every database: - -[source, hql] ----- -from Author as author -where (author.person.name, author.person.birthdate) - in (select name, birthdate from OldAuthorData) ----- - -Here we used a "row value" constructor, a seemingly pretty basic feature which is surprisingly-poorly supported. - -[TIP] -==== -Here's a very useful idiom: -[source,java] ----- -List books = - session.createSelectionQuery("from Book where isbn in :isbns", Book.class) - .setParameterList("isbns", listOfIsbns) - .getResultList(); ----- -==== - -[[hql-relational-comparisons-subqueries]] -==== Comparison operators and subqueries - -The binary comparisons we met <> may involve a quantifier, either: - -- a quantified subquery, or -- a quantifier applied to one of the functions `elements()` or `indices()` defined <>. - -The quantifiers are unary prefix operators: `all`, `every`, `any`, and `some`. - -[cols="10,10,~"] -|=== -| Subquery operator | Synonym | Semantics - -| `every` | `all` | Evaluates to true of the comparison is true for _every_ value in the result set of the subquery -| `any` | `some` | Evaluates to true of the comparison is true for _at least one_ value in the result set of the subquery -|=== - -[[hql-all-subquery-comparison-qualifier-example]] -[source, hql] ----- -from Publisher pub where 100.0 < all(select price from pub.books) ----- - -[[hql-collection-expressions-all-some-example]] -[source, hql] ----- -from Publisher pub where :title = some(select title from pub.books) ----- - -[[hql-exists-predicate]] -==== `exists` predicate - -The unary prefix `exists` operator evaluates to true if the thing to its right is nonempty. - -The thing to its right might be: - -- a subquery, or -- one of the functions `elements()` or `indices()` defined <>. - -As you can surely guess, `not exists` evaluates to true if the thing to the right _is_ empty. - -[[hql-collection-expressions-exists-example]] -[source, hql] ----- -from Author where exists elements(books) ----- -[source, hql] ----- -from Author as author -where exists ( - from Order join items - where book in elements(author.books) -) ----- - - -[[hql-collection-operators]] -==== Collection predicates - -The following operators apply to collection-valued attributes and to-many associations. - -[cols="15,15,20,~"] -|=== -| Operator | Negation | Type | Semantics - -| `is empty` | `is not empty` | Unary postfix | `true` if the collection or association on the left has no elements -| `member of` | `not member of` | Binary | `true` if the value on the left is a member of the collection or association on the right -|=== - -[[hql-empty-collection-predicate-example]] -[source, hql] ----- -from Author where books is empty ----- - -[[hql-member-of-collection-predicate-example]] -[source, hql] ----- -from Author as author, Book as book -where author member of book.authors ----- - - -[[hql-logical-operators]] -==== Logical operators - -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. - -[[root-entities-and-joins]] -== Root entities and joins - -The `from` clause, and its subordinate `join` clauses sit right at the heart of most queries. - -[[hql-from-clause]] -=== Declaring root entities: `from` and `cross join` - -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 - -An identification variable is just a name we can use to refer to an entity and its attributes from expressions in the query. -It may be any legal Java identifier. -According to the JPQL specification, identification variables must be treated as case-insensitive language elements. - -[TIP] -==== -The identification variable is actually optional, but for queries involving more than one entity it's almost always a good idea to declare one. - -This _works_, but it isn't particularly good form: -[source,hql] ----- -from Publisher join books join authors join person where ssn = :ssn ----- -==== - -Identification variables may be declared with the `as` keyword, but this is optional. - -[[hql-root-reference]] -==== Root entity references - -A root entity reference, or what the JPQL specification calls a _range variable declaration_, is a direct reference to a mapped `@Entity` type by its entity name. - -[TIP] -==== -Remember, the _entity name_ is the value of the `name` member of the `@Entity` annotation, or the unqualified Java class name by default. -==== - -[[hql-root-reference-jpql-example]] -[source, hql] ----- -select book from Book as book ----- - -In this example, `Book` is the entity name, and `book` is the identification variable. -The `as` keyword is optional. - -Alternatively, a fully-qualified Java class name may be specified. -Then Hibernate will query every entity which inherits the named type. - -[[hql-root-reference-jpql-fqn-example]] -[source, hql] ----- -select doc from org.hibernate.example.AbstractDocument where text like :pattern ----- - -Of course, there may be multiple root entities. - -[[hql-multiple-root-reference-jpql-example]] -[source, hql] ----- -select a, b -from Author a, Author b, Book book -where a in elements(book.authors) - and b in elements(book.authors) ----- - -This query may even be written using the syntax `cross join` in place of the commas: - -[[hql-cross-join-jpql-example]] -[source, hql] ----- -select a, b -from Book book - cross join Author a - cross join Author b -where a in elements(book.authors) - and b in elements(book.authors) ----- - -Of course, it's possible to write old-fashioned pre-ANSI-era joins: - -[source, hql] ----- -select book.title, publisher.name -from Book book, Publisher publisher -where book.publisher = publisher - and book.title like :titlePattern ----- - -But we never write HQL this way. - -[[hql-polymorphism]] -==== Polymorphism - -HQL and JPQL queries are inherently polymorphic. -Consider: - -[[hql-polymorphism-example]] -[source, hql] ----- -select payment from Payment as payment ----- - -This query names the `Payment` entity explicitly. -But the `CreditCardPayment` and `WireTransferPayment` entities inherit `Payment`, and so `payment` ranges over all three types. -Instances of all these entities are returned by the query. - -[NOTE] -==== -The query `from java.lang.Object` is completely legal. (But not very useful!) - -It returns every object of every mapped entity type. -==== - -// This behavior may be slightly adjusted using the `@Polymorphism` annotation. -// -// See <> for more. - -[[hql-derived-root]] -==== Derived roots - -A _derived root_ is an uncorrelated subquery which occurs in the `from` clause. - -[[hql-derived-root-example]] -[source, hql] ----- -select id, total -from ( - select ord.id as id, sum(item.book.price * item.quantity) as total - from Order as ord - join Item as item - group by ord -) -where total > 100.0 ----- - -The derived root may declare an identification variable. - -[source, hql] ----- -select stuff.id, stuff.total -from ( - select ord.id as id, sum(item.book.price * item.quantity) as total - from Order as ord - join Item as item - group by ord -) as stuff -where total > 100.0 ----- - -This feature can be used to break a more complicated query into smaller pieces. - -[IMPORTANT] -==== -We emphasize that a derived root must be an _uncorrelated_ subquery. -It may not refer to other roots declared in the same `from` clause. -==== - -A subquery may also occur in a <>, in which case it may be a correlated subquery. - -[[hql-from-cte]] -==== Common table expressions in `from` clause - -A _common table expression (CTE)_ is like a derived root with a name. -We'll discuss CTEs <>. - -[[hql-join]] -=== 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. - -An explicit join may be either: - -* an _inner join_, written as `join` or `inner join`, -* a _left outer join_, written as `left join` or `left outer join`, -* a _right outer join_, written as `right join` or `right outer join`, or -* a _full outer join_, written as `full join` or `full outer join`. - -[[hql-root-join]] -==== Explicit root joins - -An explicit root join works just like an ANSI-style join in SQL. - -[[hql-explicit-root-join-example]] -[source, hql] ----- -select book.title, publisher.name -from Book book - join Publisher publisher - on book.publisher = publisher -where book.title like :titlePattern ----- - -The join condition is written out explicitly in the `on` clause. - -[NOTE] -==== -This looks nice and familiar, but it's _not_ the most common sort of join in HQL or JPQL. -==== - -[[hql-explicit-join]] -==== Explicit association joins - -Every explicit association join specifies an entity attribute to be joined. -The specified attribute: - -* is usually a `@OneToMany`, `@ManyToMany`, `@OneToOne`, or `@ManyToOne` association, but -* it could be an `@ElementCollection`, and -* it might even be an attribute of embeddable type. - -In the case of an association or collection, the generated SQL will have a join of the same type. -(For a many-to-many association it will have _two_ joins.) -In the case of an embedded attribute, the join is purely logical and does not result in a join in the generated SQL. - -An explicit join may assign an identification variable to the joined entity. - -[[hql-explicit-inner-join-example]] -[source, hql] ----- -from Book as book - join book.publisher as publisher - join book.authors as author -where book.title like :titlePattern -select book.title, author.name, publisher.name ----- - -For an outer join, we must write our query to accommodate the possibility that the joined association is missing. - -[[hql-explicit-outer-join-example]] -[source, hql] ----- -from Book as book - left join book.publisher as publisher - join book.authors as author -where book.title like :titlePattern -select book.title, author.name, ifnull(publisher.name, '-') ----- - -For further information about collection-valued association references, see <>. - -[[hql-explicit-join-conditions]] -==== Explicit association joins with join conditions - -The `with` or `on` clause allows explicit qualification of the join conditions. - -[NOTE] -==== -The specified join conditions are _added_ to the join conditions specified by the foreign key association. -That's why, historically, HQL uses the keword `with` here: -"with" emphasizes that the new condition doesn't _replace_ the original join conditions. - -The `with` keyword is specific to Hibernate. JPQL uses `on`. -==== - -Join conditions occurring in the `with` or `on` clause are added to the `on` clause in the generated SQL. - -[[hql-explicit-join-with-example]] -[source, hql] ----- -from Book as book - left join book.publisher as publisher - with publisher.closureDate is not null - left join book.authors as author - with author.type <> COLLABORATION -where book.title like :titlePattern -select book.title, author.name, publisher.name ----- - -// The following query is arguably less clear, but it's semantically identical: -// -// [[hql-explicit-join-jpql-on-example]] -// [source, hql] -// ---- -// from Book as book -// left join book.publisher as publisher -// on publisher.closureDate is not null -// left join book.authors as author -// on author.type <> COLLABORATION -// where book.title like :titlePattern -// select book.title, author.name, publisher.name -// ---- - -[[hql-explicit-fetch-join]] -==== Association fetching: `join fetch` - -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β€”for lovers of verbosityβ€”``left outer join fetch``, returns all the base entities, including those which have no associated joined entity. - -[IMPORTANT] -==== -This is one of the most important features of Hibernate. -To achieve acceptable performance with HQL, you'll need to use `join fetch` quite often. -Without it, you'll quickly run into the dreaded "n+1 selects" problem. -==== - -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]] -[source, hql] ----- -select book -from Book as book - left join fetch book.publisher - join fetch book.authors ----- - -In this example, we used a left outer join for `book.publisher` because we also wanted to obtain books with no publisher, but a regular inner join for `book.authors` because every book has at least one author. - -A query may have more than one fetch join, but be aware that: - -* 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 ``join fetch``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 usually be avoided in limited or paged queries. -This includes: - -- queries executed with limits specified via the `setFirstResult()` and `setMaxResults()` methods of `Query`, or -- queries with a limit or offset declared in HQL, described below in <>. - -Nor should they be used with the `scroll()` and `stream()` methods of the `Query` interface. -==== - -Fetch joins are disallowed in subqueries, where they would make no sense. - -[[hql-join-treat]] -==== Joins with typecasts - -An explicit join may narrow the type of the joined entity using `treat()`. - -[[hql-join-treat-example]] -[source, hql] ----- -from Order as ord - join treat(ord.payments as CreditCardPayment) as creditCardPayment -where length(creditCardPayment.cardNumber) between 16 and 20 ----- - -Here, the identification variable `ccp` declared to the right of `treat()` has the narrowed type `CreditCardPayment`, instead of the declared type `Payment`. -This allows the attribute `cardNumber` declared by the subtype `CreditCardPayment` to be referenced in the rest of the query. - -See <> for more information about `treat()`. - -[[hql-join-derived]] -==== Subqueries in joins - -A `join` clause may contain a subquery, either: - -- an uncorrelated subquery, which is almost the same as a <>, except that it may have an `on` restriction, or -- a _lateral join_, which is a correlated subquery, and may refer to other roots declared earlier in the same `from` clause. - -The `lateral` keyword just distinguishes the two cases. - -[[hql-derived-join-example]] -[source, hql] ----- -from Phone as phone - left join ( - select call.duration as duration, call.phone.id as cid - from Call as call - order by call.duration desc - limit 1 - ) as longest on cid = phone.id -where phone.number = :phoneNumber -select longest.duration ----- - -This query may also be expressed using a `lateral` join: - -[source, hql] ----- -from Phone as phone - left join lateral ( - select call.duration as duration - from phone.calls as call - order by call.duration desc - limit 1 - ) as longest -where phone.number = :phoneNumber -select longest.duration ----- - -A lateral join may be an inner or left outer join, but not a right join, nor a full join. - -[TIP] -==== -Traditional SQL doesn't allow correlated subqueries in the `from` clause. -A lateral join is essentially just that, but with a different syntax to what you might expect. - -On some databases, `join lateral` is written `cross apply`. -And on Postgres it's plain `lateral`, without `join`. - -It's almost as if they're _deliberately trying_ to confuse us. -==== - -Lateral joins are particularly useful for computing top-N elements of multiple groups. - -[IMPORTANT] -==== -Most databases support some flavor of `join lateral`, and Hibernate emulates the feature for databases which don't. -But emulation is neither very efficient, nor does it support all possible query shapes, so it's important to test on your target database. -==== - -[[hql-implicit-join]] -==== Implicit association joins (path expressions) - -It's not necessary to explicitly `join` every entity that occurs in a query. -Instead, entity associations may be _navigated_, just like in Java: - -* if an attribute is of embedded type, or is a to-one association, it may be further navigated, but -* if an attribute is of basic type, it is considered terminal, and may not be further navigated, and -* if an attribute is collection-valued, or is a to-many association, it may be navigated, but only with the help of `value()`, `element()`, or `key()`. - -It's clear that: - -* A path expression like `author.name` with only two elements just refers to state held directly by an entity with an alias `author` defined in `from` or `join`. -* But a longer path expression, for example, `author.person.name`, might refer to state held by an associated entity. - (Alternatively, it might refer to state held by an embedded class.) - -In the second case, Hibernate with automatically add a join to the generated SQL if necessary. - -[[hql-implicit-join-example]] -[source, hql] ----- -from Book as book -where book.publisher.name like :pubName ----- - -As in this example, implicit joins usually appear outside the `from` clause of the HQL query. -However, they always affect the `from` clause of the SQL query. - -The example above is equivalent to: - -[[hql-implicit-join-alt]] -[source, hql] -[%unbreakable] ----- -select book -from Book as book - join book.publisher pub -where pub.name like :pubName ----- - -Note that: - -* Implicit joins are always treated as inner joins. -* Multiple occurrences of the same implicit join always refer to the same SQL join. - -This query: - -[[hql-implicit-join-alias-example]] -[source, hql] ----- -select book -from Book as book -where book.publisher.name like :pubName - and book.publisher.closureDate is null ----- - -results in just one SQL join, and is just a different way to write: - -[[hql-implicit-join-alias-alt]] -[source, hql] ----- -select book -from Book as book - join book.publisher as pub -where pub.name like :pubName - and pub.closureDate is null ----- - -[[hql-collection-valued-associations]] -==== Joining collections and many-valued associations - -When a join involves a collection or many-valued association, the declared identification variable refers to the _elements_ of the collection, that is: - -- to the elements of a `Set`, -- to the elements of a `List`, not to their indices in the list, or -- to the values of a `Map`, not to their keys. - -[[hql-collection-valued-associations-example]] -[source, hql] ----- -select publisher.name, author.name -from Publisher as publisher - join publisher.books as book - join book.authors author -where author.name like :namePattern ----- - -In this example, the identification variable `author` is of type `Author`, the element type of the list `Book.authors`. -But if we need to refer to the index of an `Author` in the list, we need some extra syntax. - -You might recall that we mentioned <> and <> a bit earlier. -These functions may be applied to the identification variable declared in a collection join or many-valued association join. - -[cols="12,20,~,~"] -|=== -| Function | Applies to | Interpretation | Notes - -| `value()` or `element()` | Any collection | The collection element or map entry value -| Often optional. -| `index()` | Any `List` with an index column | The index of the element in the list -| For backward compatibility, it's also an alternative to ``key()``, when applied to a map. -| `key()` | Any `Map` | The key of the entry in the list | If the key is of entity type, it may be further navigated. -| `entry()` | Any `Map` | The map entry, that is, the `Map.Entry` of key and value. -| Only legal as a terminal path, and only allowed in the `select` clause. -|=== - -In particular, `index()` and `key()` obtain a reference to a list index or map key. - -[[hql-collection-qualification-example]] -[source, hql] -[%unbreakable] ----- -select book.title, author.name, index(author) -from Book as book - join book.authors as author ----- -[source, hql] -[%unbreakable] ----- -select publisher.name, leadAuthor.name -from Publisher as publisher - join publisher.books as book - join book.authors leadAuthor -where leadAuthor.name like :namePattern - and index(leadAuthor) == 0 ----- - - -[[hql-implicit-collection-join]] -==== Implicit joins involving collections - -A path expression like `book.authors.name` is not considered legal. -We can't just navigate a many-valued association with this syntax. - -Instead, the functions `element()`, `index()`, `key()`, and `value()` may be applied to a path expression to express an implicit join. -So we must write `element(book.authors).name`. - -[[hql-collection-implicit-join-example]] -[source, hql] ----- -select book.title, element(book.authors).name, index(book.authors) -from Book book ----- - -An element of an indexed collection (an array, list, or map) may even be identified using the index operator: - -[[hql-collection-index-operator-example]] -[source, hql] ----- -select publisher.name, book.authors[0].name -from Publisher as publisher - join publisher.books as book -where book.authors[0].name like :namePattern ----- - -[[selection-projection-aggregation]] -== Selection, projection, and aggregation - -Joining is one kind of _relational operation_. -It's an operation that produces relations (tables) from other relations. -Such operations, taken together, form the _relational algebra_. - -We must now understand the rest of this family: restriction a.k.a. selection, projection, aggregation, union/intersection, and, finally, ordering and limiting, operations which are not strictly part of the calculus of relations, but which usually come along for the ride because they're very _useful_. - -We'll start with the operation that's easiest to understand. - -[[hql-where-clause]] -=== Restriction: `where` - -The `where` clause restricts the results returned by a `select` query or limits the scope of an `update` or `delete` query. - -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 <>. -Therefore, we'll move quickly onto the next, and more interesting, operation. - -[[hql-aggregation]] -=== Aggregation: `group by` and `having` - -An aggregate query is one with <> in its projection list. -It collapses multiple rows into a single row. -Aggregate queries are used for summarizing and analysing data. - -An aggregate query might have a `group by` clause. -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. -If an aggregate query _doesn't_ have a `group by` clause, it always produces a single row of results. - -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]] -==== Aggregation and grouping: `group by` - -The `group by` clause looks quite similar to the `select` clauseβ€”it has a list of grouped items, but: - -- 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. - -The BNF for a grouped item is just: - -[[hql-group-by-item-bnf]] -[source, antlrv4] ----- -include::{extrasdir}/group_by_item_bnf.txt[] ----- - -Consider the following queries: - -[source, hql] -[%unbreakable] ----- -select book.isbn, - sum(quantity) as totalSold, - sum(quantity * book.price) as totalBilled -from Item -where book.isbn = :isbn ----- - -[[hql-group-by-example]] -[source, hql] -[%unbreakable] ----- -select book.isbn, - year(order.dateTime) as year, - sum(quantity) as yearlyTotalSold, - sum(quantity * book.price) as yearlyTotalBilled -from Item -where book.isbn = :isbn -group by year(order.dateTime) ----- - -The first query calculates complete totals over all orders in years. -The second calculates totals for each year, after grouping the orders by year. - -[[hql-group-by-rollup-cube]] -==== Totals and subtotals: `rollup` and `cube` - -The special functions `rollup()` and `cube()` may be used in the `group by` clause, when supported by the database. -The semantics are identical to SQL. - -These functions are especially useful for reporting. - -* A `group by` clause with `rollup()` is used to produce subtotals and grand totals. -* A `group by` clause with `cube()` allows totals for every combination of columns. - -[[hql-having]] -==== Aggregation and restriction: `having` - -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 <>, we calculated totals for every year for which data was available. -But our dataset might extend far back into the past, perhaps even as far back as those terrible dark ages before Hibernate 2.0. -So let's restrict our result set to data from our own more civilized times: - -[[hql-group-by-having-example]] -[source, hql] ----- -select book.isbn, - year(order.dateTime) as year, - sum(quantity) as yearlyTotalSold, - sum(quantity * book.price) as yearlyTotalBilled -from Item -where book.isbn = :isbn -group by year(order.dateTime) -having year(order.dateTime) > 2003 - and sum(quantity) > 0 ----- - -The `having` clause follows the same rules as the `where` clause and is also just a logical predicate. -The `having` restriction is applied after grouping and aggregation has already been performed, whereas the `where` clause is applied before the data is grouped or aggregated. - -[[hql-select-clause]] -=== Projection: `select` - -The `select` list identifies which objects and values to return as the query results. - -NOTE: This operation is called _projection_. - -Any of the expression types discussed in <> may occur in the projection list, unless otherwise noted. - -TIP: If a query has no explicit `select` list, the projection is inferred from the entities and joins occurring in the `from` clause, together with the result type specified by the call to `createQuery()`. -It's better to specify the projection explicitly, except in the simplest cases. - -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]] -[source, java] ----- -List results = - entityManager.createQuery("select title, left(book.text, 200) from Book", - Object[].class) - .getResultList(); -for (var result : results) { - String title = (String) result[0]; - String preamble = (String) result[1]; -} ----- -[source, java] ----- -List results = - entityManager.createQuery("select title as title, left(book.text, 200) as preamble from Book", - Tuple.class) - .getResultList(); -for (Tuple tuple : tuples) { - String title = tuple.get("title", String.class); - String preamble = tuple.get("preamble", String.class); -} ----- - -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]] -[source, antlrv4] ----- -include::{extrasdir}/select_item_bnf.txt[] ----- - -where `instantiatiationArgs` is essentially a nested projection list. - -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]] -==== Instantiation: `select new` - -The `select new` construct packages the query results into a user-written Java class instead of an array. - -[[hql-select-clause-dynamic-instantiation-example]] -[source, java] ----- -record BookSummary(String title, String summary) {} - -List results = - entityManager.createQuery("select new BookSummary(title, left(book.text, 200)) from Book", - BookSummary.class) - .getResultList(); -for (var result : results) { - String title = result.title(); - String preamble = resukt.summary(); -} ----- - -The class 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 and are _not_ associated with the session. -==== - -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]] -[source, java] ----- -List results = - entityManager.createQuery("select new map(title as title, left(book.text, 200) as summary) from Book", - Map.class) - .getResultList(); ----- - -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]] -[source, java] ----- -List results = - entityManager.createQuery("select new list(title as title, left(book.text, 200) as summary) from Book", - List.class) - .getResultList(); ----- - -[NOTE] -==== -This is an older syntax, that predates JPQL. -In hindsight, it's hard to see what advantage `List` offers compared to `Object[]`. -We mention it here only for completeness. -On the other hand, `Map` is a perfectly fine alternative `Tuple`, but of course isn't portable to other implementations of JPA. -==== - -[[hql-distinct]] -==== Duplicate removal: `distinct` - -The `distinct` keyword helps remove duplicate results from the query result list. -It's only effect is to add `distinct` to the generated SQL. - -[[hql-distinct-projection-query-example]] -[source, hql] ----- -select distinct lastName from Person ----- -[source, hql] ----- -select distinct author -from Publisher as pub - join pub.books as book - join book.authors as author -where pub.id = :pid ----- - - -[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, in particular, `distinct` should not be used for this purpose. -==== - -[[hql-aggregate-functions]] -==== Aggregate functions - -It's common to have aggregate functions like `count()`, `sum()`, and `max()` in a select list. -Aggregate functions are special functions that reduce the size of the result set. - -The standard aggregate functions defined in both ANSI SQL and JPQL are these ones: - -[cols="30,~,~,^15"] -|=== -| Aggregate function | Argument type | Result type | JPA standard / ANSI SQL standard - -| `count()`, including `count(distinct)`, `count(all)`, and `count(*)` | Any | `Long` | βœ”/βœ” -| `avg()` | Any numeric type | `Double` | βœ”/βœ” -| `min()` | Any numeric type, or string | Same as the argument type | βœ”/βœ” -| `max()` | Any numeric type, or string | Same as the argument type | βœ”/βœ” -| `sum()` | Any numeric type | See table below | βœ”/βœ” -| `var_pop()`, `var_samp()` | Any numeric type | `Double` | βœ–/βœ” -| `stddev_pop()`, `stddev_samp()` | Any numeric type | `Double` | βœ–/βœ” -|=== - -[[hql-aggregate-functions-example]] -[source, hql] ----- -select count(distinct item.book) -from Item as item -where year(item.order.dateTime) = :year ----- -[source, hql] ----- -select sum(item.quantity) as totalSales -from Item as item -where item.book.isbn = :isbn ----- -[source, hql] ----- -select - year(item.order.dateTime) as year, - sum(item.quantity) as yearlyTotal -from Item as item -where item.book.isbn = :isbn -group by year(item.order.dateTime) ----- -[source, hql] ----- -select - month(item.order.dateTime) as month, - avg(item.quantity) as monthlyAverage -from Item as item -where item.book.isbn = :isbn -group by month(item.order.dateTime) ----- - -In the case of `sum()`, the rules for assigning a result type are: -|=== -| Argument type | Result type - -| Any integral numeric type except `BigInteger` | `Long` -| Any floating point numeric type | `Double` -| `BigInteger` | `BigInteger` -| `BigDecimal` | `BigDecimal` -|=== - -HQL defines two additional aggregate functions which accept a logical predicate as an argument. - -[cols="30,~,~,^15"] -|=== -| Aggregate function | Argument type | Result type | JPA standard - -| `any()` | Logical predicate | `Boolean` | βœ– -| `every()` | Logical predicate | `Boolean` | βœ– -|=== - -We may write, for example, `every(p.amount < 1000.0)`. - -Below, we'll meet the <>. - -NOTE: Aggregate functions usually appear in the `select` clause, but control over aggregation is the responsibility of the `group by` clause, as described <>. - -[[hql-aggregate-functions-collections]] -==== Aggregate functions and collections - -The `elements()` and `indices()` functions we met <> let us apply aggregate functions to a collection: - -[cols="18,15,~,~"] -|=== -| New syntax | Legacy HQL function | Applies to | Purpose - -| `max(elements(x))` | `maxelement(x)` | Any collection with sortable elements | The maximum element or map value -| `min(elements(x))` | `minelement(x)` | Any collection with sortable elements | The minimum element or map value -| `sum(elements(x))` | β€” | Any collection with numeric elements | The sum of the elements or map values -| `avg(elements(x))` | β€” | Any collection with numeric elements | The average of the elements or map values -| `max(indices(x))` | `maxindex(x)` | Indexed collections (lists and maps) | The maximum list index or map key -| `min(indices(x))` | `minindex(x)` | Indexed collections (lists and maps) | The minimum list index or map key -| `sum(indices(x))` | β€” | Indexed collections (lists and maps) | The sum of the list indexes or map keys -| `avg(indices(x))` | β€” | Indexed collections (lists and maps) | The average of the list indexes or map keys -|=== - -These operations are mostly useful when working with ``@ElementCollection``s. - -[[hql-collection-expressions-example]] -[source, hql] ----- -select title, max(indices(authors))+1, max(elements(editions)) from Book ----- - -[[hql-aggregate-functions-filter]] -==== Aggregate functions with restriction: `filter` - -All aggregate functions support the inclusion of a _filter clause_, a sort of mini-`where` applying a restriction to just one item of the select list: - -[[hql-aggregate-functions-filter-example]] -[source, hql] ----- -select - year(item.order.dateTime) as year, - sum(item.quantity) filter (where not item.order.fulfilled) as unfulfilled, - sum(item.quantity) filter (where item.order.fulfilled) as fulfilled, - sum(item.quantity * item.book.price) filter (where item.order.paid) -from Item as item -where item.book.isbn = :isbn -group by year(item.order.dateTime) ----- - -The BNF for the `filter` clause is simple: - -[source,antlrv4] ----- -filterClause - : "FILTER" "(" "WHERE" predicate ")" ----- - -[[hql-aggregate-functions-orderedset]] -==== Ordered set aggregate functions: `within group` - -An _ordered set aggregate function_ is a special aggregate function which has: - -- not only an optional filter clause, as above, but also -- a `within group` clause containing a mini-`order by` specification. - -The BNF for `within group` is straightforward: - -[source,antlrv4] ----- -withinGroupClause - : "WITHIN" "GROUP" "(" "ORDER" "BY" sortSpecification ("," sortSpecification)* ")" ----- - -There are two main types of ordered set aggregate function: - -- an _inverse distribution function_ calculates a value that characterizes the distribution of values within the group, for example, `percentile_cont(0.5)` is the median, and `percentile_cont(0.25)` is the lower quartile. -- a _hypothetical set function_ determines the position of a "hypothetical" value within the ordered set of values. - -The following ordered set aggregate functions are available on many platforms: - -[cols="30,~"] -|=== -| Type | Functions - -| Inverse distribution functions | `mode()`, `percentile_cont()`, `percentile_disc()` -| Hypothetical set functions | `rank()`, `dense_rank()`, `percent_rank()`, `cume_dist()` -| Other | `listagg()` -|=== - -This query calculates the median price of a book: - -[source, hql] ----- -select percentile_cont(0.5) - within group (order by price) -from Book ----- - -This query finds the percentage of books with prices less than 10 dollars: - -[source, hql] ----- -select 100 * percent_rank(10.0) - within group (order by price) -from Book ----- - -Actually, the most widely-supported ordered set aggregate function is one which builds a string by concatenating the values within a group. -This function has different names on different databases, but HQL abstracts these differences, andβ€”following ANSI SQLβ€”calls it `listagg()`. - -[[hql-aggregate-functions-within-group-example]] -[source, hql] -[%unbreakable] ----- -select listagg(title, ', ') - within group (order by isbn) -from Book -group by elements(authors) ----- - -This very useful function produces a string by concatenation of the aggregated values of its argument. - -[[hql-aggregate-functions-window]] -==== Window functions: `over` - -A _window function_ is one which also has an `over` clause, for example: - -[source,hql] -[%unbreakable] ----- -select - item.order.dateTime, - sum(item.quantity) - over (order by item.order.dateTime) - as runningTotal -from Item item ----- - -This query returns a running total of sales over time. -That is, the `sum()` is taken over a window comprising the current row of the result set, together with all previous rows. - -A window function application may optionally specify any of the following clauses: - -[cols="23,18,~"] -|=== -| Optional clause | Keyword | Purpose - -| _Partitioning_ of the result set | `partition by` | Very similar to `group by`, but doesn't collapse each partition to a single row -| _Ordering_ of the partition | `order by` | Specifies the order of rows within a partition -| _Windowing_ | `range`, `rows`, or `groups` | Defines the bounds of a window frame within a partition -| _Restriction_ | `filter` | As aggregate functions, window functions may optionally specify a filter -|=== - -For example, we may partition the running total by book: - -[source,hql] ----- -select - item.book.isbn, - item.order.dateTime, - sum(item.quantity) - over (partition by item.book - order by item.order.dateTime) - as runningTotal -from Item item ----- - -Every partition runs in isolation, that is, rows can't leak across partitions. - -The full syntax for window function application is amazingly involved, as shown by this BNF: - -[source,antlrv4] ----- -overClause - : "OVER" "(" partitionClause? orderByClause? frameClause? ")" - -partitionClause - : "PARTITION" "BY" expression ("," expression)* - -frameClause - : ("RANGE"|"ROWS"|"GROUPS") frameStart frameExclusion? - | ("RANGE"|"ROWS"|"GROUPS") "BETWEEN" frameStart "AND" frameEnd frameExclusion? - -frameStart - : "CURRENT" "ROW" - | "UNBOUNDED" "PRECEDING" - | expression "PRECEDING" - | expression "FOLLOWING" - -frameEnd - : "CURRENT" "ROW" - | "UNBOUNDED" "FOLLOWING" - | expression "PRECEDING" - | expression "FOLLOWING" - -frameExclusion - : "EXCLUDE" "CURRENT" "ROW" - | "EXCLUDE" "GROUP" - | "EXCLUDE" "TIES" - | "EXCLUDE" "NO" "OTHERS" ----- - -Window functions are similar to aggregate functions in the sense that they compute some value based on a "frame" comprising multiple rows. -But unlike aggregate functions, window functions don't flatten rows within a window frame. - -[discrete] -===== Window frames - -The _window frame_ is the set of rows within a given partition that is passed to the window function. -There's a different window frame for each row of the result set. -In our example, the window frame comprised all the preceding rows within the partition, that is, all the rows with the same `item.book` and with an earlier `item.order.dateTime`. - -The boundary of the window frame is controlled via the windowing clause, which may specify one of the following modes: - -[cols="8,40,20,~"] -|=== -| Mode | Definition | Example | Interpretation - -|`rows` | Frame bounds defined by a given number of rows | `rows 5 preceding` | The previous 5 rows in the partition -| `groups` | Frame bounds defined by a given number of _peer groups_, rows belonging to the same peer group if they are assigned the same position by `order by` | `groups 5 preceding` | The rows in the previous 5 peer groups in the partition -| `range` | Frame bounds defined by a maximum difference in _value_ of the expression used to `order by` | `range between 1.0 preceding and 1.0 following` | The rows whose `order by` expression differs by a maximum absolute value of `1.0` from the current row -|=== - -The frame exclusion clause allows excluding rows around the current row: - -[cols="20,~"] -|=== -| Option | Interpretation - -| `exclude current row` | Excludes the current row -| `exclude group` | Excludes rows of the peer group of the current row -| `exclude ties` | Excludes rows of the peer group of the current row except the current row -| `exclude no others` | The default, does not exclude anything -|=== - -By default, the window frame is defined as `rows between unbounded preceding and current row exclude no others`, meaning every row up to and including the current row. - -[IMPORTANT] -==== -The modes `range` and `groups`, along with frame exclusion modes, are not available on every database. -==== -[discrete] -===== Widely supported window functions - -The following window functions are available on all major platforms: - -[cols="15,~,30"] -|=== -| Window function | Purpose | Signature - -| `row_number()` | The position of the current row within its frame | `row_number()` -| `lead()` | The value of a subsequent row in the frame | `lead(x)`, `lead(x, i, x)` -| `lag()` | The value of a previous row in the frame | `lag(x)`, `lag(x, i, x)` -| `first_value()` | The value of a first row in the frame | `first_value(x)` -| `last_value()` | The value of a last row in the frame | `last_value(x)` -| `nth_value()` | The value of the `n`th row in the frame | `nth_value(x, n)` -|=== - -In principle every aggregate or ordered set aggregate function might also be used as a window function, just by specifying `over`, but not every function is supported on every database. - -[IMPORTANT] -==== -Window functions and ordered set aggregate functions aren't available on every database. -Even where they are available, support for particular features varies widely between databases. -Therefore, we won't waste time going into further detail here. -For more information about the syntax and semantics of these functions, consult the documentation for your dialect of SQL. -==== - -[[hql-set-operators]] -=== Operations on result sets: `union`, `intersect`, and `except` - -These operators apply not to expressions, but to entire result sets: - -- `union` and `union all`, -- `intersect` and `intersect all`, and -- `except` and `except all`. - -Just like in SQL, `all` suppresses the elimination of duplicate results. - -[[hql-union-example]] -[source, hql] ----- -select nomDePlume from Author where nomDePlume is not null -union -select name from Person ----- - -[[hql-order-by]] -=== Sorting: `order by` - -By default, the results of the query are returned in an arbitrary order. - -[NOTE] -==== -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 `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 <>, -* 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]] -[source, antlrv4] ----- -include::{extrasdir}/order_by_item_bnf.txt[] ----- - -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's an ambiguity with respect to null values. -Therefore, the sorting of null values may be explicitly specified: - -[cols="20,~"] -|=== -| Precedence | Interpretation - -| `nulls first` | Puts null values at the beginning of the result set -| `nulls last` | Puts them at the end -|=== - -[[hql-order-by-example]] -[source, hql] ----- -select title, publisher.name -from Book -order by title, publisher.name nulls last ----- -[source, hql] ----- -select book.isbn, - year(order.dateTime) as year, - sum(quantity) as yearlyTotalSold, - sum(quantity * book.price) as yearlyTotalBilled -from Item -where book.isbn = :isbn -group by year(order.dateTime) -having year(order.dateTime) > 2000 - and sum(quantity) > 0 -order by yearlyTotalSold desc, year desc ----- - -Queries with an ordered result list may have limits or pagination. - -[[hql-limit-offset]] -==== 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. -The `limit` and `offset` clauses are an alternative to the use of `setMaxResults()` and `setFirstResult()` respectively, -and may similarly be used for pagination. - -[TIP] -==== -If the `limit` or `offset` is parameterized, it's much easier to use `setMaxResults()` or `setFirstResult()`. -==== - -The SQL `fetch` syntax is supported as an alternative: - -[cols="25,45,~"] -|=== -| Short form | Verbose form | Purpose - -| `limit 10` | `fetch first 10 rows only` | Limit result set -| `limit 10 offset 20` | `offset 20 rows fetch next 10 rows only` | Paginate result set -|=== - -The BNF gets a bit complicated: - -[[hql-limit-offset-bnf]] -[source, antlrv4] ----- -include::{extrasdir}/limit_offset_bnf.txt[] ----- - -These two queries are identical: - -[[hql-limit-example]] -[source, hql] ----- -select title from Book -order by title, published desc -limit 50 ----- -[source, hql] ----- -select title from Book -order by title, published desc -fetch first 50 rows only ----- - -These are well-defined limits: the number of results returned by the database will be limited to 50, as promised. -But not every query is quite so well-behaved. - -[NOTE] -==== -_Limiting_ certainly _isn't_ a well-defined relational operation, and must be used with care. - -In particular, limits don't play well with <>. -==== - -This next query is accepted by HQL, and no more than 50 results are returned by `getResultList()`, just as expected: - -[[hql-bad-limit-example]] -[source, hql] ----- -select title from Book - join fetch authors -order by title, published desc -limit 50 ----- -However, if you log the SQL executed by Hibernate, you'll notice something wrong: - -[source, sql] ----- -select - b1_0.isbn, - a1_0.books_isbn, - a1_0.authors_ORDER, - a1_1.id, - a1_1.bio, - a1_1.name, - a1_1.person_id, - b1_0.price, - b1_0.published, - b1_0.publisher_id, - b1_0.title -from - Book b1_0 -join - (Book_Author a1_0 - join - Author a1_1 - on a1_1.id=a1_0.authors_id) - on b1_0.isbn=a1_0.books_isbn -order by - b1_0.title, - b1_0.published desc ----- - -What happened to the `limit` clause? - -[%unbreakable] -[IMPORTANT] -==== -When limits or pagination are combined with a fetch join, Hibernate must retrieve all matching results from the database and _apply the limit in memory_! - -This _almost certainly_ isn't the behavior you were hoping for, and in general will exhibit _terrible_ performance characteristics. -==== - -[[hql-with-cte]] -=== Common table expressions - -A _common table expression_ or CTE may be thought of as a sort of named subquery. -Any query with an uncorrelated subquery can in principle be rewritten so that the subquery occurs in the `with` clause. - -But CTEs have capabilities that subqueries don't have. -The `with` clause lets us: - -- specify materialization hints, and -- write recursive queries. - -On databases which don't support CTEs natively, Hibernate attempts to rewrite any HQL query with CTEs as a SQL query with subqueries. -This is impossible for recursive queries, unfortunately. - -Let's take a quick look at the BNF: - -[source,antlrv4] -[%unbreakable] ----- -withClause - : "WITH" cte ("," cte)* - -cte - : identifier AS ("NOT"? "MATERIALIZED")? "(" queryExpression ")" - searchClause? cycleClause? ----- - -The `with` clause comes right at the start of a query. -It may declare multiple CTEs with different names. - -[source, hql] -[%unbreakable] ----- -with - paid as ( - select ord.id as oid, sum(payment.amount) as amountPaid - from Order as ord - left join ord.payments as payment - group by ord - having local datetime - ord.dateTime < 365 day - ), - owed as ( - select ord.id as oid, sum(item.quantity*item.book.price) as amountOwed - from Order as ord - left join ord.items as item - group by ord - having local datetime - ord.dateTime < 365 day - ) -select id, paid.amountPaid, owed.amountOwed -from Order -where paid.amountPaid < owed.amountOwed - and paid.oid = id and owed.oid = id ----- - -Notice that if we rewrote this query using subqueries, it would look quite a lot clumsier. - -[[materialization-hints]] -==== Materialization hints - -The `materialized` keyword is a hint to the database that the subquery should be separately executed and its results stored in a temporary table. - -On the other hand, its nemesis, `not materialized`, is a hint that the subquery should be inlined at each use site, with each usage optimized independently. - -[CAUTION] -==== -The precise impact of materialization hints is quite platform-dependant. -==== - -Our example query from above hardly changes. -We just add `materialized` to the CTE declarations. - -[[hql-cte-materialized-example]] -[source, hql] -[%unbreakable] ----- -with - paid as materialized ( - select ord.id as oid, sum(payment.amount) as amountPaid - from Order as ord - left join ord.payments as payment - group by ord - having local datetime - ord.dateTime < 365 day - ), - owed as materialized ( - select ord.id as oid, sum(item.quantity*item.book.price) as amountOwed - from Order as ord - left join ord.items as item - group by ord - having local datetime - ord.dateTime < 365 day - ) -select id, paid.amountPaid, owed.amountOwed -from Order -where paid.amountPaid < owed.amountOwed - and paid.oid = id and owed.oid = id ----- - -[[recursive-queries]] -==== Recursive queries - -A _recursive query_ is one where the CTE is defined self-referentially. -Recursive queries follow a very particular pattern. -The CTE is defined as a union of: - -- a base subquery returning an initial set of rows where the recursion begins, -- a recursively-executed subquery which returns additional rows by joining against the CTE itself. - -Let's demonstrate this with an example. - -First we'll need some sort of tree-like entity: - -[source,java] -[%unbreakable] ----- -@Entity -class Node { - @Id Long id; - String text; - @ManyToOne Node parent; -} ----- - -We may obtain a tree of ``Node``s with the following recursive query: - -[[hql-cte-recursive-example]] -[source, hql] -[%unbreakable] ----- -with Tree as ( - /* base query */ - select root.id as id, root.text as text, 0 as level - from Node root - where root.parent is null - union all - /* recursion */ - select child.id as id, child.text as text, level+1 as level - from Tree parent - join Node child on child.parent.id = parent.id -) -select text, level -from Tree ----- - -When querying a tree-like of data structure, the base subquery usually returns the root node or nodes. -The recursively-executed subquery returns the children of the current set of nodes. -It's executed repeatedly with the results of the previous execution. -Recursion terminates when the recursively-executed subquery returns no new nodes. - -[CAUTION] -==== -Hibernate cannot emulate recursive queries on databases which don't support them natively. -==== - -Now, if a graph contains cycles, that is, if it isn't a tree, the recursion might never terminate. - -==== Cycle detection - -The `cycle` clause enables cycle detection, and aborts the recursion if a node is encountered twice. - -[[hql-cte-recursive-example]] -[source, hql] -[%unbreakable] ----- -with Tree as ( - /* base query */ - select root.id as id, root.text as text, 0 as level - from Node root - where root.parent is null - union all - /* recursion */ - select child.id as id, child.text as text, level+1 as level - from Tree parent - join Node child on child.parent.id = parent.id -) cycle id set abort to 'aborted!' default '' /* cycle detection */ -select text, level, abort -from Tree -order by level ----- - -Here: - -- the `id` column is used to detect cycles, and -- the `abort` column is set to the string value `'aborted!'` if a cycle is detected. - -Hibernate emulates the `cycle` clause on databases which don't support it natively. - -The BNF for `cycle` is: - -[[hql-cte-recursive-cycle-bnf-example]] -[source, antlrv4] -[%unbreakable] ----- -cycleClause - : "CYCLE" identifier ("," identifier)* - "SET" identifier ("TO" literal "DEFAULT" literal)? - ("USING" identifier)? ----- - -The column optionally specified by `using` holds the path to the current row. - -==== Ordering depth-first or breadth-first - -The `search` clause allows us to control whether we would like the results of our query returned in an order that emulates a depth-first recursive search, or a breadth-first recursive search. - -In our query above, we explicitly coded a `level` column that holds the recursion depth, and ordered our result set according to this depth. -With the `search` clause, that bookkeeping is already taken care of for us. - -For depth-first search, we have: - -[source, hql] -[%unbreakable] ----- -with Tree as ( - /* base query */ - select root.id as id, root.text as text - from Node root - where root.parent is null - union all - /* recursion */ - select child.id as id, child.text as text - from Tree parent - join Node child on child.parent.id = parent.id -) search depth first by id set level /* depth-first search */ -from Tree -order by level ----- - -And for breadth-first search, we only need to change a single keyword: - -[source, hql] -[%unbreakable] ----- -with Tree as ( - /* base query */ - select root.id as id, root.text as text - from Node root - where root.parent is null - union all - /* recursion */ - select child.id as id, child.text as text - from Tree parent - join Node child on child.parent.id = parent.id -) search breadth first by id set level /* breadth-first search */ -from Tree -order by level desc ----- - -Hibernate emulates the `search` clause on databases which don't support it natively. - -The BNF for `search` is: - -[[hql-cte-recursive-search-bnf-example]] -[source, antlrv4] -[%unbreakable] ----- -searchClause - : "SEARCH" ("BREADTH"|"DEPTH") "FIRST" - "BY" searchSpecifications - "SET" identifier - -searchSpecifications - : searchSpecification ("," searchSpecification)* - -searchSpecification - : identifier sortDirection? nullsPrecedence? ----- diff --git a/documentation/src/main/asciidoc/querylanguage/Preface.adoc b/documentation/src/main/asciidoc/querylanguage/Preface.adoc new file mode 100644 index 0000000000..07169665e2 --- /dev/null +++ b/documentation/src/main/asciidoc/querylanguage/Preface.adoc @@ -0,0 +1,15 @@ +[[preface]] +== Preface + +Hibernate 6 is a major redesign of the world's most popular and feature-rich ORM solution. +The redesign has touched almost every subsystem of Hibernate, including the APIs, mapping annotations, and, above all else, the query language. + +This is the second time HQL has been completely reimplemented from scratch, but the first time in more than fifteen years. +In this new incarnation, HQL is far more powerful, and the HQL compiler much more robust. + +At long last, HQL has a feature set to match that of modern dialects of SQL, and is able to take full advantage of the power of modern SQL databases. + +This document is a reference guide to the full feature set of the language, and is the only up-to-date source for those who wish to learn how to write HQL effectively in Hibernate 6. + +But if you don't already know Hibernate, don't start here. +First, read _An introduction to Hibernate 6_, and then come back. diff --git a/documentation/src/main/asciidoc/querylanguage/Relational.adoc b/documentation/src/main/asciidoc/querylanguage/Relational.adoc new file mode 100644 index 0000000000..b6274f9229 --- /dev/null +++ b/documentation/src/main/asciidoc/querylanguage/Relational.adoc @@ -0,0 +1,1089 @@ +[[selection-projection-aggregation]] +== Selection, projection, and aggregation + +Joining is one kind of _relational operation_. +It's an operation that produces relations (tables) from other relations. +Such operations, taken together, form the _relational algebra_. + +We must now understand the rest of this family: restriction a.k.a. selection, projection, aggregation, union/intersection, and, finally, ordering and limiting, operations which are not strictly part of the calculus of relations, but which usually come along for the ride because they're very _useful_. + +We'll start with the operation that's easiest to understand. + +[[where-clause]] +=== Restriction + +The `where` clause restricts the results returned by a `select` query or limits the scope of an `update` or `delete` query. + +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 <>. +Therefore, we'll move quickly onto the next, and more interesting, operation. + +[[aggregation]] +=== Aggregation + +An aggregate query is one with <> in its projection list. +It collapses multiple rows into a single row. +Aggregate queries are used for summarizing and analysing data. + +An aggregate query might have a `group by` clause. +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. +If an aggregate query _doesn't_ have a `group by` clause, it always produces a single row of results. + +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. + +[[group-by]] +==== Aggregation and grouping + +The `group by` clause looks quite similar to the `select` clauseβ€”it has a list of grouped items, but: + +- 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. + +The BNF for a grouped item is just: + +[[group-by-item-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/group_by_item_bnf.txt[] +---- + +Consider the following queries: + +[source, hql] +[%unbreakable] +---- +select book.isbn, + sum(quantity) as totalSold, + sum(quantity * book.price) as totalBilled +from Item +where book.isbn = :isbn +---- + +[[group-by-example]] +[source, hql] +[%unbreakable] +---- +select book.isbn, + year(order.dateTime) as year, + sum(quantity) as yearlyTotalSold, + sum(quantity * book.price) as yearlyTotalBilled +from Item +where book.isbn = :isbn +group by year(order.dateTime) +---- + +The first query calculates complete totals over all orders in years. +The second calculates totals for each year, after grouping the orders by year. + +[[group-by-rollup-cube]] +==== Totals and subtotals + +The special functions `rollup()` and `cube()` may be used in the `group by` clause, when supported by the database. +The semantics are identical to SQL. + +These functions are especially useful for reporting. + +* A `group by` clause with `rollup()` is used to produce subtotals and grand totals. +* A `group by` clause with `cube()` allows totals for every combination of columns. + +[[having]] +==== Aggregation and restriction + +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 <>, we calculated totals for every year for which data was available. +But our dataset might extend far back into the past, perhaps even as far back as those terrible dark ages before Hibernate 2.0. +So let's restrict our result set to data from our own more civilized times: + +[[group-by-having-example]] +[source, hql] +---- +select book.isbn, + year(order.dateTime) as year, + sum(quantity) as yearlyTotalSold, + sum(quantity * book.price) as yearlyTotalBilled +from Item +where book.isbn = :isbn +group by year(order.dateTime) +having year(order.dateTime) > 2003 + and sum(quantity) > 0 +---- + +The `having` clause follows the same rules as the `where` clause and is also just a logical predicate. +The `having` restriction is applied after grouping and aggregation has already been performed, whereas the `where` clause is applied before the data is grouped or aggregated. + +[[select-clause]] +=== Projection + +The `select` list identifies which objects and values to return as the query results. + +NOTE: This operation is called _projection_. + +Any of the expression types discussed in <> may occur in the projection list, unless otherwise noted. + +TIP: If a query has no explicit `select` list, the projection is inferred from the entities and joins occurring in the `from` clause, together with the result type specified by the call to `createQuery()`. +It's better to specify the projection explicitly, except in the simplest cases. + +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`. + +[[select-clause-projection-example]] +[source, java] +---- +List results = + entityManager.createQuery("select title, left(book.text, 200) from Book", + Object[].class) + .getResultList(); +for (var result : results) { + String title = (String) result[0]; + String preamble = (String) result[1]; +} +---- +[source, java] +---- +List results = + entityManager.createQuery("select title as title, left(book.text, 200) as preamble from Book", + Tuple.class) + .getResultList(); +for (Tuple tuple : tuples) { + String title = tuple.get("title", String.class); + String preamble = tuple.get("preamble", String.class); +} +---- + +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: + +[[select-item-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/select_item_bnf.txt[] +---- + +where `instantiatiationArgs` is essentially a nested projection list. + +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. + +[[select-new]] +==== Instantiation + +The `select new` construct packages the query results into a user-written Java class instead of an array. + +[[select-clause-dynamic-instantiation-example]] +[source, java] +---- +record BookSummary(String title, String summary) {} + +List results = + entityManager.createQuery("select new BookSummary(title, left(book.text, 200)) from Book", + BookSummary.class) + .getResultList(); +for (var result : results) { + String title = result.title(); + String preamble = resukt.summary(); +} +---- + +The class 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 and are _not_ associated with the session. +==== + +Alternatively, using the syntax `select new map`, the query may specify that each result should be packaged as a map: + +[[select-clause-dynamic-map-instantiation-example]] +[source, java] +---- +List results = + entityManager.createQuery("select new map(title as title, left(book.text, 200) as summary) from Book", + Map.class) + .getResultList(); +---- + +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: + +[[select-clause-dynamic-list-instantiation-example]] +[source, java] +---- +List results = + entityManager.createQuery("select new list(title as title, left(book.text, 200) as summary) from Book", + List.class) + .getResultList(); +---- + +[NOTE] +==== +This is an older syntax, that predates JPQL. +In hindsight, it's hard to see what advantage `List` offers compared to `Object[]`. +We mention it here only for completeness. +On the other hand, `Map` is a perfectly fine alternative `Tuple`, but of course isn't portable to other implementations of JPA. +==== + +[[distinct]] +==== Duplicate removal + +The `distinct` keyword helps remove duplicate results from the query result list. +It's only effect is to add `distinct` to the generated SQL. + +[[distinct-projection-query-example]] +[source, hql] +---- +select distinct lastName from Person +---- +[source, hql] +---- +select distinct author +from Publisher as pub + join pub.books as book + join book.authors as author +where pub.id = :pid +---- + + +[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, in particular, `distinct` should not be used for this purpose. +==== + +[[aggregate-functions]] +==== Aggregate functions + +It's common to have aggregate functions like `count()`, `sum()`, and `max()` in a select list. +Aggregate functions are special functions that reduce the size of the result set. + +The standard aggregate functions defined in both ANSI SQL and JPQL are these ones: + +[cols="30,~,~,^15"] +|=== +| Aggregate function | Argument type | Result type | JPA standard / ANSI SQL standard + +| `count()`, including `count(distinct)`, `count(all)`, and `count(*)` | Any | `Long` | βœ”/βœ” +| `avg()` | Any numeric type | `Double` | βœ”/βœ” +| `min()` | Any numeric type, or string | Same as the argument type | βœ”/βœ” +| `max()` | Any numeric type, or string | Same as the argument type | βœ”/βœ” +| `sum()` | Any numeric type | See table below | βœ”/βœ” +| `var_pop()`, `var_samp()` | Any numeric type | `Double` | βœ–/βœ” +| `stddev_pop()`, `stddev_samp()` | Any numeric type | `Double` | βœ–/βœ” +|=== + +[[aggregate-functions-example]] +[source, hql] +---- +select count(distinct item.book) +from Item as item +where year(item.order.dateTime) = :year +---- +[source, hql] +---- +select sum(item.quantity) as totalSales +from Item as item +where item.book.isbn = :isbn +---- +[source, hql] +---- +select + year(item.order.dateTime) as year, + sum(item.quantity) as yearlyTotal +from Item as item +where item.book.isbn = :isbn +group by year(item.order.dateTime) +---- +[source, hql] +---- +select + month(item.order.dateTime) as month, + avg(item.quantity) as monthlyAverage +from Item as item +where item.book.isbn = :isbn +group by month(item.order.dateTime) +---- + +In the case of `sum()`, the rules for assigning a result type are: +|=== +| Argument type | Result type + +| Any integral numeric type except `BigInteger` | `Long` +| Any floating point numeric type | `Double` +| `BigInteger` | `BigInteger` +| `BigDecimal` | `BigDecimal` +|=== + +HQL defines two additional aggregate functions which accept a logical predicate as an argument. + +[cols="30,~,~,^15"] +|=== +| Aggregate function | Argument type | Result type | JPA standard + +| `any()` | Logical predicate | `Boolean` | βœ– +| `every()` | Logical predicate | `Boolean` | βœ– +|=== + +We may write, for example, `every(p.amount < 1000.0)`. + +Below, we'll meet the <>. + +NOTE: Aggregate functions usually appear in the `select` clause, but control over aggregation is the responsibility of the `group by` clause, as described <>. + +[[aggregate-functions-collections]] +==== Aggregate functions and collections + +The `elements()` and `indices()` functions we met <> let us apply aggregate functions to a collection: + +[cols="18,15,~,~"] +|=== +| New syntax | Legacy HQL function | Applies to | Purpose + +| `max(elements(x))` | `maxelement(x)` | Any collection with sortable elements | The maximum element or map value +| `min(elements(x))` | `minelement(x)` | Any collection with sortable elements | The minimum element or map value +| `sum(elements(x))` | β€” | Any collection with numeric elements | The sum of the elements or map values +| `avg(elements(x))` | β€” | Any collection with numeric elements | The average of the elements or map values +| `max(indices(x))` | `maxindex(x)` | Indexed collections (lists and maps) | The maximum list index or map key +| `min(indices(x))` | `minindex(x)` | Indexed collections (lists and maps) | The minimum list index or map key +| `sum(indices(x))` | β€” | Indexed collections (lists and maps) | The sum of the list indexes or map keys +| `avg(indices(x))` | β€” | Indexed collections (lists and maps) | The average of the list indexes or map keys +|=== + +These operations are mostly useful when working with ``@ElementCollection``s. + +[[collection-expressions-example]] +[source, hql] +---- +select title, max(indices(authors))+1, max(elements(editions)) from Book +---- + +[[aggregate-functions-filter]] +==== Aggregate functions with restriction + +All aggregate functions support the inclusion of a _filter clause_, a sort of mini-`where` applying a restriction to just one item of the select list: + +[[aggregate-functions-filter-example]] +[source, hql] +---- +select + year(item.order.dateTime) as year, + sum(item.quantity) filter (where not item.order.fulfilled) as unfulfilled, + sum(item.quantity) filter (where item.order.fulfilled) as fulfilled, + sum(item.quantity * item.book.price) filter (where item.order.paid) +from Item as item +where item.book.isbn = :isbn +group by year(item.order.dateTime) +---- + +The BNF for the `filter` clause is simple: + +[source,antlrv4] +---- +filterClause + : "FILTER" "(" "WHERE" predicate ")" +---- + +[[aggregate-functions-orderedset]] +==== Ordered set aggregate functions + +An _ordered set aggregate function_ is a special aggregate function which has: + +- not only an optional filter clause, as above, but also +- a `within group` clause containing a mini-`order by` specification. + +The BNF for `within group` is straightforward: + +[source,antlrv4] +---- +withinGroupClause + : "WITHIN" "GROUP" "(" "ORDER" "BY" sortSpecification ("," sortSpecification)* ")" +---- + +There are two main types of ordered set aggregate function: + +- an _inverse distribution function_ calculates a value that characterizes the distribution of values within the group, for example, `percentile_cont(0.5)` is the median, and `percentile_cont(0.25)` is the lower quartile. +- a _hypothetical set function_ determines the position of a "hypothetical" value within the ordered set of values. + +The following ordered set aggregate functions are available on many platforms: + +[cols="30,~"] +|=== +| Type | Functions + +| Inverse distribution functions | `mode()`, `percentile_cont()`, `percentile_disc()` +| Hypothetical set functions | `rank()`, `dense_rank()`, `percent_rank()`, `cume_dist()` +| Other | `listagg()` +|=== + +This query calculates the median price of a book: + +[source, hql] +---- +select percentile_cont(0.5) + within group (order by price) +from Book +---- + +This query finds the percentage of books with prices less than 10 dollars: + +[source, hql] +---- +select 100 * percent_rank(10.0) + within group (order by price) +from Book +---- + +Actually, the most widely-supported ordered set aggregate function is one which builds a string by concatenating the values within a group. +This function has different names on different databases, but HQL abstracts these differences, andβ€”following ANSI SQLβ€”calls it `listagg()`. + +[[aggregate-functions-within-group-example]] +[source, hql] +[%unbreakable] +---- +select listagg(title, ', ') + within group (order by isbn) +from Book +group by elements(authors) +---- + +This very useful function produces a string by concatenation of the aggregated values of its argument. + +[[aggregate-functions-window]] +==== Window functions + +A _window function_ is one which also has an `over` clause, for example: + +[source,hql] +[%unbreakable] +---- +select + item.order.dateTime, + sum(item.quantity) + over (order by item.order.dateTime) + as runningTotal +from Item item +---- + +This query returns a running total of sales over time. +That is, the `sum()` is taken over a window comprising the current row of the result set, together with all previous rows. + +A window function application may optionally specify any of the following clauses: + +[cols="23,18,~"] +|=== +| Optional clause | Keyword | Purpose + +| _Partitioning_ of the result set | `partition by` | Very similar to `group by`, but doesn't collapse each partition to a single row +| _Ordering_ of the partition | `order by` | Specifies the order of rows within a partition +| _Windowing_ | `range`, `rows`, or `groups` | Defines the bounds of a window frame within a partition +| _Restriction_ | `filter` | As aggregate functions, window functions may optionally specify a filter +|=== + +For example, we may partition the running total by book: + +[source,hql] +---- +select + item.book.isbn, + item.order.dateTime, + sum(item.quantity) + over (partition by item.book + order by item.order.dateTime) + as runningTotal +from Item item +---- + +Every partition runs in isolation, that is, rows can't leak across partitions. + +The full syntax for window function application is amazingly involved, as shown by this BNF: + +[source,antlrv4] +---- +overClause + : "OVER" "(" partitionClause? orderByClause? frameClause? ")" + +partitionClause + : "PARTITION" "BY" expression ("," expression)* + +frameClause + : ("RANGE"|"ROWS"|"GROUPS") frameStart frameExclusion? + | ("RANGE"|"ROWS"|"GROUPS") "BETWEEN" frameStart "AND" frameEnd frameExclusion? + +frameStart + : "CURRENT" "ROW" + | "UNBOUNDED" "PRECEDING" + | expression "PRECEDING" + | expression "FOLLOWING" + +frameEnd + : "CURRENT" "ROW" + | "UNBOUNDED" "FOLLOWING" + | expression "PRECEDING" + | expression "FOLLOWING" + +frameExclusion + : "EXCLUDE" "CURRENT" "ROW" + | "EXCLUDE" "GROUP" + | "EXCLUDE" "TIES" + | "EXCLUDE" "NO" "OTHERS" +---- + +Window functions are similar to aggregate functions in the sense that they compute some value based on a "frame" comprising multiple rows. +But unlike aggregate functions, window functions don't flatten rows within a window frame. + +[discrete] +===== Window frames + +The _window frame_ is the set of rows within a given partition that is passed to the window function. +There's a different window frame for each row of the result set. +In our example, the window frame comprised all the preceding rows within the partition, that is, all the rows with the same `item.book` and with an earlier `item.order.dateTime`. + +The boundary of the window frame is controlled via the windowing clause, which may specify one of the following modes: + +[cols="8,40,20,~"] +|=== +| Mode | Definition | Example | Interpretation + +|`rows` | Frame bounds defined by a given number of rows | `rows 5 preceding` | The previous 5 rows in the partition +| `groups` | Frame bounds defined by a given number of _peer groups_, rows belonging to the same peer group if they are assigned the same position by `order by` | `groups 5 preceding` | The rows in the previous 5 peer groups in the partition +| `range` | Frame bounds defined by a maximum difference in _value_ of the expression used to `order by` | `range between 1.0 preceding and 1.0 following` | The rows whose `order by` expression differs by a maximum absolute value of `1.0` from the current row +|=== + +The frame exclusion clause allows excluding rows around the current row: + +[cols="20,~"] +|=== +| Option | Interpretation + +| `exclude current row` | Excludes the current row +| `exclude group` | Excludes rows of the peer group of the current row +| `exclude ties` | Excludes rows of the peer group of the current row except the current row +| `exclude no others` | The default, does not exclude anything +|=== + +By default, the window frame is defined as `rows between unbounded preceding and current row exclude no others`, meaning every row up to and including the current row. + +[IMPORTANT] +==== +The modes `range` and `groups`, along with frame exclusion modes, are not available on every database. +==== +[discrete] +===== Widely supported window functions + +The following window functions are available on all major platforms: + +[cols="15,~,30"] +|=== +| Window function | Purpose | Signature + +| `row_number()` | The position of the current row within its frame | `row_number()` +| `lead()` | The value of a subsequent row in the frame | `lead(x)`, `lead(x, i, x)` +| `lag()` | The value of a previous row in the frame | `lag(x)`, `lag(x, i, x)` +| `first_value()` | The value of a first row in the frame | `first_value(x)` +| `last_value()` | The value of a last row in the frame | `last_value(x)` +| `nth_value()` | The value of the `n`th row in the frame | `nth_value(x, n)` +|=== + +In principle every aggregate or ordered set aggregate function might also be used as a window function, just by specifying `over`, but not every function is supported on every database. + +[IMPORTANT] +==== +Window functions and ordered set aggregate functions aren't available on every database. +Even where they are available, support for particular features varies widely between databases. +Therefore, we won't waste time going into further detail here. +For more information about the syntax and semantics of these functions, consult the documentation for your dialect of SQL. +==== + +[[set-operators]] +=== Operations on result sets + +These operators apply not to expressions, but to entire result sets: + +- `union` and `union all`, +- `intersect` and `intersect all`, and +- `except` and `except all`. + +Just like in SQL, `all` suppresses the elimination of duplicate results. + +[[union-example]] +[source, hql] +---- +select nomDePlume from Author where nomDePlume is not null +union +select name from Person +---- + +[[order-by]] +=== Sorting + +By default, the results of the query are returned in an arbitrary order. + +[NOTE] +==== +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 `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 <>, +- 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: + +[[order-by-item-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/order_by_item_bnf.txt[] +---- + +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's an ambiguity with respect to null values. +Therefore, the sorting of null values may be explicitly specified: + +[cols="20,~"] +|=== +| Precedence | Interpretation + +| `nulls first` | Puts null values at the beginning of the result set +| `nulls last` | Puts them at the end +|=== + +[[order-by-example]] +[source, hql] +---- +select title, publisher.name +from Book +order by title, publisher.name nulls last +---- +[source, hql] +---- +select book.isbn, + year(order.dateTime) as year, + sum(quantity) as yearlyTotalSold, + sum(quantity * book.price) as yearlyTotalBilled +from Item +where book.isbn = :isbn +group by year(order.dateTime) +having year(order.dateTime) > 2000 + and sum(quantity) > 0 +order by yearlyTotalSold desc, year desc +---- + +Queries with an ordered result list may have limits or pagination. + +[[limit-offset]] +==== 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. +The `limit` and `offset` clauses are an alternative to the use of `setMaxResults()` and `setFirstResult()` respectively, +and may similarly be used for pagination. + +[TIP] +==== +If the `limit` or `offset` is parameterized, it's much easier to use `setMaxResults()` or `setFirstResult()`. +==== + +The SQL `fetch` syntax is supported as an alternative: + +[cols="25,45,~"] +|=== +| Short form | Verbose form | Purpose + +| `limit 10` | `fetch first 10 rows only` | Limit result set +| `limit 10 offset 20` | `offset 20 rows fetch next 10 rows only` | Paginate result set +|=== + +The BNF gets a bit complicated: + +[[limit-offset-bnf]] +[source, antlrv4] +---- +include::{extrasdir}/limit_offset_bnf.txt[] +---- + +These two queries are identical: + +[[limit-example]] +[source, hql] +---- +select title from Book +order by title, published desc +limit 50 +---- +[source, hql] +---- +select title from Book +order by title, published desc +fetch first 50 rows only +---- + +These are well-defined limits: the number of results returned by the database will be limited to 50, as promised. +But not every query is quite so well-behaved. + +[NOTE] +==== +_Limiting_ certainly _isn't_ a well-defined relational operation, and must be used with care. + +In particular, limits don't play well with <>. +==== + +This next query is accepted by HQL, and no more than 50 results are returned by `getResultList()`, just as expected: + +[[bad-limit-example]] +[source, hql] +---- +select title from Book + join fetch authors +order by title, published desc +limit 50 +---- +However, if you log the SQL executed by Hibernate, you'll notice something wrong: + +[source, sql] +---- +select + b1_0.isbn, + a1_0.books_isbn, + a1_0.authors_ORDER, + a1_1.id, + a1_1.bio, + a1_1.name, + a1_1.person_id, + b1_0.price, + b1_0.published, + b1_0.publisher_id, + b1_0.title +from + Book b1_0 +join + (Book_Author a1_0 + join + Author a1_1 + on a1_1.id=a1_0.authors_id) + on b1_0.isbn=a1_0.books_isbn +order by + b1_0.title, + b1_0.published desc +---- + +What happened to the `limit` clause? + +[%unbreakable] +[IMPORTANT] +==== +When limits or pagination are combined with a fetch join, Hibernate must retrieve all matching results from the database and _apply the limit in memory_! + +This _almost certainly_ isn't the behavior you were hoping for, and in general will exhibit _terrible_ performance characteristics. +==== + +[[with-cte]] +=== Common table expressions + +A _common table expression_ or CTE may be thought of as a sort of named subquery. +Any query with an uncorrelated subquery can in principle be rewritten so that the subquery occurs in the `with` clause. + +But CTEs have capabilities that subqueries don't have. +The `with` clause lets us: + +- specify materialization hints, and +- write recursive queries. + +On databases which don't support CTEs natively, Hibernate attempts to rewrite any HQL query with CTEs as a SQL query with subqueries. +This is impossible for recursive queries, unfortunately. + +Let's take a quick look at the BNF: + +[source,antlrv4] +[%unbreakable] +---- +withClause + : "WITH" cte ("," cte)* + +cte + : identifier AS ("NOT"? "MATERIALIZED")? "(" queryExpression ")" + searchClause? cycleClause? +---- + +The `with` clause comes right at the start of a query. +It may declare multiple CTEs with different names. + +[source, hql] +[%unbreakable] +---- +with + paid as ( + select ord.id as oid, sum(payment.amount) as amountPaid + from Order as ord + left join ord.payments as payment + group by ord + having local datetime - ord.dateTime < 365 day + ), + owed as ( + select ord.id as oid, sum(item.quantity*item.book.price) as amountOwed + from Order as ord + left join ord.items as item + group by ord + having local datetime - ord.dateTime < 365 day + ) +select id, paid.amountPaid, owed.amountOwed +from Order +where paid.amountPaid < owed.amountOwed + and paid.oid = id and owed.oid = id +---- + +Notice that if we rewrote this query using subqueries, it would look quite a lot clumsier. + +[[materialization-hints]] +==== Materialization hints + +The `materialized` keyword is a hint to the database that the subquery should be separately executed and its results stored in a temporary table. + +On the other hand, its nemesis, `not materialized`, is a hint that the subquery should be inlined at each use site, with each usage optimized independently. + +[CAUTION] +==== +The precise impact of materialization hints is quite platform-dependant. +==== + +Our example query from above hardly changes. +We just add `materialized` to the CTE declarations. + +[[cte-materialized-example]] +[source, hql] +[%unbreakable] +---- +with + paid as materialized ( + select ord.id as oid, sum(payment.amount) as amountPaid + from Order as ord + left join ord.payments as payment + group by ord + having local datetime - ord.dateTime < 365 day + ), + owed as materialized ( + select ord.id as oid, sum(item.quantity*item.book.price) as amountOwed + from Order as ord + left join ord.items as item + group by ord + having local datetime - ord.dateTime < 365 day + ) +select id, paid.amountPaid, owed.amountOwed +from Order +where paid.amountPaid < owed.amountOwed + and paid.oid = id and owed.oid = id +---- + +[[recursive-queries]] +==== Recursive queries + +A _recursive query_ is one where the CTE is defined self-referentially. +Recursive queries follow a very particular pattern. +The CTE is defined as a union of: + +- a base subquery returning an initial set of rows where the recursion begins, +- a recursively-executed subquery which returns additional rows by joining against the CTE itself. + +Let's demonstrate this with an example. + +First we'll need some sort of tree-like entity: + +[source,java] +[%unbreakable] +---- +@Entity +class Node { + @Id Long id; + String text; + @ManyToOne Node parent; +} +---- + +We may obtain a tree of ``Node``s with the following recursive query: + +[[cte-recursive-example]] +[source, hql] +[%unbreakable] +---- +with Tree as ( + /* base query */ + select root.id as id, root.text as text, 0 as level + from Node root + where root.parent is null + union all + /* recursion */ + select child.id as id, child.text as text, level+1 as level + from Tree parent + join Node child on child.parent.id = parent.id +) +select text, level +from Tree +---- + +When querying a tree-like of data structure, the base subquery usually returns the root node or nodes. +The recursively-executed subquery returns the children of the current set of nodes. +It's executed repeatedly with the results of the previous execution. +Recursion terminates when the recursively-executed subquery returns no new nodes. + +[CAUTION] +==== +Hibernate cannot emulate recursive queries on databases which don't support them natively. +==== + +Now, if a graph contains cycles, that is, if it isn't a tree, the recursion might never terminate. + +==== Cycle detection + +The `cycle` clause enables cycle detection, and aborts the recursion if a node is encountered twice. + +[[cte-cycle-example]] +[source, hql] +[%unbreakable] +---- +with Tree as ( + /* base query */ + select root.id as id, root.text as text, 0 as level + from Node root + where root.parent is null + union all + /* recursion */ + select child.id as id, child.text as text, level+1 as level + from Tree parent + join Node child on child.parent.id = parent.id +) cycle id set abort to 'aborted!' default '' /* cycle detection */ +select text, level, abort +from Tree +order by level +---- + +Here: + +- the `id` column is used to detect cycles, and +- the `abort` column is set to the string value `'aborted!'` if a cycle is detected. + +Hibernate emulates the `cycle` clause on databases which don't support it natively. + +The BNF for `cycle` is: + +[[cte-recursive-cycle-bnf-example]] +[source, antlrv4] +[%unbreakable] +---- +cycleClause + : "CYCLE" identifier ("," identifier)* + "SET" identifier ("TO" literal "DEFAULT" literal)? + ("USING" identifier)? +---- + +The column optionally specified by `using` holds the path to the current row. + +==== Ordering depth-first or breadth-first + +The `search` clause allows us to control whether we would like the results of our query returned in an order that emulates a depth-first recursive search, or a breadth-first recursive search. + +In our query above, we explicitly coded a `level` column that holds the recursion depth, and ordered our result set according to this depth. +With the `search` clause, that bookkeeping is already taken care of for us. + +For depth-first search, we have: + +[source, hql] +[%unbreakable] +---- +with Tree as ( + /* base query */ + select root.id as id, root.text as text + from Node root + where root.parent is null + union all + /* recursion */ + select child.id as id, child.text as text + from Tree parent + join Node child on child.parent.id = parent.id +) search depth first by id set level /* depth-first search */ +from Tree +order by level +---- + +And for breadth-first search, we only need to change a single keyword: + +[source, hql] +[%unbreakable] +---- +with Tree as ( + /* base query */ + select root.id as id, root.text as text + from Node root + where root.parent is null + union all + /* recursion */ + select child.id as id, child.text as text + from Tree parent + join Node child on child.parent.id = parent.id +) search breadth first by id set level /* breadth-first search */ +from Tree +order by level desc +---- + +Hibernate emulates the `search` clause on databases which don't support it natively. + +The BNF for `search` is: + +[[cte-recursive-search-bnf-example]] +[source, antlrv4] +[%unbreakable] +---- +searchClause + : "SEARCH" ("BREADTH"|"DEPTH") "FIRST" + "BY" searchSpecifications + "SET" identifier + +searchSpecifications + : searchSpecification ("," searchSpecification)* + +searchSpecification + : identifier sortDirection? nullsPrecedence? +---- diff --git a/release/release.gradle b/release/release.gradle index af43b0fbfe..a330a92f11 100644 --- a/release/release.gradle +++ b/release/release.gradle @@ -247,6 +247,14 @@ task stageIntroduction(type: Copy) { into "${buildDir}/documentation/introduction" } +task stageQL(type: Copy) { + group 'Release' + + dependsOn ':documentation:renderQL' + + from "${project( ':documentation' ).buildDir}/asciidoc/querylanguage" + into "${buildDir}/documentation/querylanguage" +} task stageUserGuide(type: Copy) { group 'Release'