Skip to content

Commit 90a752a

Browse files
committed
HHH-15328 Add support for CTE WITH clause
1 parent 215d411 commit 90a752a

File tree

178 files changed

+7245
-1487
lines changed

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

178 files changed

+7245
-1487
lines changed

documentation/src/main/asciidoc/userguide/chapters/query/hql/QueryLanguage.adoc

Lines changed: 140 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -89,6 +89,7 @@ Most of the complexity here arises from the interplay of set operators (`union`,
8989

9090
We'll describe the various clauses of a query later in this chapter, but to summarize, a query might have:
9191

92+
* a `with` clause, specifying <<hql-with-cte,named subqueries>> to be used in the following query,
9293
* a `select` list, specifying a <<hql-select-clause,projection>> (the things to return from the query),
9394
* a `from` clause and joins, <<hql-from-clause,specifying>> the entities involved in the query, and how they're <<hql-join,related>> to each other,
9495
* a `where` clause, specifying a <<hql-where-clause,restriction>>,
@@ -1559,6 +1560,16 @@ It may not refer to other roots declared in the same `from` clause.
15591560
15601561
A subquery may also occur in a <<hql-join-derived, join>>, in which case it may be a correlated subquery.
15611562
1563+
[[hql-from-cte]]
1564+
==== Common table expressions in `from` clause
1565+
1566+
A _Common table expression (CTE)_ is like a derived root with a name. The big difference is,
1567+
that the name can be referred to multiple times. It must declare an identification variable.
1568+
1569+
The CTE name can be used for a `from` clause root or a `join`, similar to entity names.
1570+
1571+
Refer to the <<hql-with-cte,with clause>> chapter for details about CTEs.
1572+
15621573
[[hql-join]]
15631574
=== Declaring joined entities
15641575
@@ -2477,3 +2488,132 @@ This _almost certainly_ isn't the behavior you were hoping for, and in general w
24772488
====
24782489
24792490
In the next chapter we'll see a completely different way to write queries in Hibernate.
2491+
2492+
[[hql-with-cte]]
2493+
==== With clause
2494+
2495+
The `with` clause allows to specify _common table expressions (CTEs)_ which can be imagined like named subqueries.
2496+
Every uncorrelated subquery can be factored to a CTE in the `with` clause. The semantics are equivalent.
2497+
2498+
The `with` clause offers features beyond naming subqueries though:
2499+
2500+
* Specify materialization hints
2501+
* Recursive querying
2502+
2503+
===== Materialization hint
2504+
2505+
The materialization hint `MATERIALIZED` or `NOT MATERIALIZED` can be applied to tell the DBMS whether a CTE should
2506+
or shouldn't be materialized. Consult the database manual of the respective database for the exact meaning of the hint.
2507+
2508+
Usually, one can expect that `MATERIALIZED` will cause the subquery to be executed separately and saved into a temporary table,
2509+
whereas `NOT MATERIALIZED` will cause the subquery to be inlined into every use site and considered during optimizations separately.
2510+
2511+
[[hql-cte-materialized-example]]
2512+
====
2513+
[source, JAVA, indent=0]
2514+
----
2515+
include::{sourcedir}/HQLTest.java[tags=hql-cte-materialized-example, indent=0]
2516+
----
2517+
====
2518+
2519+
===== Recursive querying
2520+
2521+
The main use case for the `with` clause is to define a name for a subquery,
2522+
such that this subquery can refer to itself, which ultimately enables recursive querying.
2523+
2524+
Recursive CTEs must follow a very particular shape, which is
2525+
2526+
* Base query part
2527+
* `union` or `union all`
2528+
* Recursive query part
2529+
2530+
[[hql-cte-recursive-example]]
2531+
====
2532+
[source, JAVA, indent=0]
2533+
----
2534+
include::{sourcedir}/HQLTest.java[tags=hql-cte-recursive-example, indent=0]
2535+
----
2536+
====
2537+
2538+
The base query part represents the initial set of rows. When fetching a tree of data,
2539+
the base query part usually is the tree root.
2540+
2541+
The recursive query part is executed again and again until it produces no new rows.
2542+
The result of such a CTE is the base query part result _unioned_ together with all recursive query part executions.
2543+
Depending on whether `union all` or `union` (`distinct`) is used, duplicate rows are preserved or not.
2544+
2545+
Recursive queries additionally can have
2546+
2547+
* a `search` clause to hint the DBMS whether to use breadth or depth first searching
2548+
* a `cycle` clause to hint the DBMS how to determine that a cycle was reached
2549+
2550+
Defining the `search` clause requires specifying a name for an attribute in the `set` sub-clause,
2551+
that will be added to the CTE type and allows ordering results according to the search order.
2552+
2553+
[[hql-cte-recursive-search-bnf-example]]
2554+
====
2555+
[source, antlrv4, indent=0]
2556+
----
2557+
searchClause
2558+
: "SEARCH" ("BREADTH"|"DEPTH") "FIRST BY" searchSpecifications "SET" identifier
2559+
;
2560+
2561+
searchSpecifications
2562+
: searchSpecification ("," searchSpecification)*
2563+
;
2564+
2565+
searchSpecification
2566+
: identifier sortDirection? nullsPrecedence?
2567+
;
2568+
----
2569+
====
2570+
2571+
A DBMS has two possible orders when executing the recursive query part
2572+
2573+
* Depth first - handle the *newest* produced rows by the recursive query part first
2574+
* Breadth first - handle the *oldest* produced rows by the recursive query part first
2575+
2576+
[[hql-cte-recursive-search-example]]
2577+
====
2578+
[source, JAVA, indent=0]
2579+
----
2580+
include::{sourcedir}/HQLTest.java[tags=hql-cte-recursive-search-example, indent=0]
2581+
----
2582+
====
2583+
2584+
Recursive processing can lead to cycles which might lead to queries executing forever.
2585+
The `cycle` clause hints the DBMS which CTE attributes to track for the cycle detection.
2586+
It requires specifying a name for a cycle mark attribute in the `set` sub-clause,
2587+
that will be added to the CTE type and allows detecting if a cycle occurred for a result.
2588+
2589+
By default, the cycle mark attribute will be set to `true` when a cycle is detected and `false` otherwise.
2590+
The values to use can be explicitly specified through the `to` and `default` sub-clauses.
2591+
Optionally, it's also possible to specify a cycle path attribute name through the `using` clause
2592+
The cycle path attribute can be used to understand the traversal path that lead to a result.
2593+
2594+
[[hql-cte-recursive-cycle-bnf-example]]
2595+
====
2596+
[source, antlrv4, indent=0]
2597+
----
2598+
cycleClause
2599+
: "CYCLE" cteAttributes "SET" identifier ("TO" literal "DEFAULT" literal)? ("USING" identifier)?
2600+
;
2601+
----
2602+
====
2603+
2604+
[[hql-cte-recursive-cycle-example]]
2605+
====
2606+
[source, JAVA, indent=0]
2607+
----
2608+
include::{sourcedir}/HQLTest.java[tags=hql-cte-recursive-cycle-example, indent=0]
2609+
----
2610+
====
2611+
2612+
[IMPORTANT]
2613+
====
2614+
Hibernate merely translates recursive CTEs but doesn't attempt to emulate the feature.
2615+
Therefore, this feature will only work if the database supports recursive CTEs.
2616+
Hibernate does emulate the `search` and `cycle` clauses though if necessary, so you can safely use that.
2617+
2618+
Note that most modern database versions support recursive CTEs already.
2619+
====

documentation/src/main/asciidoc/userguide/chapters/query/hql/extras/statement_select_bnf.txt

Lines changed: 30 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,7 @@ selectStatement
22
: queryExpression
33

44
queryExpression
5-
: orderedQuery (setOperator orderedQuery)*
5+
: withClause? orderedQuery (setOperator orderedQuery)*
66

77
orderedQuery
88
: (query | "(" queryExpression ")") queryOrder?
@@ -29,4 +29,32 @@ join
2929

3030
joinTarget
3131
: path variable?
32-
| "LATERAL"? "(" subquery ")" variable?
32+
| "LATERAL"? "(" subquery ")" variable?
33+
34+
withClause
35+
: "WITH" cte ("," cte)*
36+
;
37+
38+
cte
39+
: identifier AS ("NOT"? "MATERIALIZED")? "(" queryExpression ")" searchClause? cycleClause?
40+
;
41+
42+
cteAttributes
43+
: identifier ("," identifier)*
44+
;
45+
46+
searchClause
47+
: "SEARCH" ("BREADTH"|"DEPTH") "FIRST BY" searchSpecifications "SET" identifier
48+
;
49+
50+
searchSpecifications
51+
: searchSpecification ("," searchSpecification)*
52+
;
53+
54+
searchSpecification
55+
: identifier sortDirection? nullsPrecedence?
56+
;
57+
58+
cycleClause
59+
: "CYCLE" cteAttributes "SET" identifier ("TO" literal "DEFAULT" literal)? ("USING" identifier)?
60+
;

documentation/src/test/java/org/hibernate/userguide/hql/HQLTest.java

Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3133,6 +3133,102 @@ public void test_hql_derived_root_example() {
31333133
});
31343134
}
31353135

3136+
@Test
3137+
public void test_hql_cte_materialized_example() {
3138+
3139+
doInJPA(this::entityManagerFactory, entityManager -> {
3140+
//tag::hql-cte-materialized-example[]
3141+
List<Tuple> calls = entityManager.createQuery(
3142+
"with data as materialized(" +
3143+
" select p.person as owner, c.payment is not null as payed " +
3144+
" from Call c " +
3145+
" join c.phone p " +
3146+
" where p.number = :phoneNumber" +
3147+
")" +
3148+
"select d.owner, d.payed " +
3149+
"from data d",
3150+
Tuple.class)
3151+
.setParameter("phoneNumber", "123-456-7890")
3152+
.getResultList();
3153+
//end::hql-cte-materialized-example[]
3154+
});
3155+
}
3156+
3157+
@Test
3158+
@RequiresDialectFeature( DialectChecks.SupportsRecursiveCtes.class )
3159+
public void test_hql_cte_recursive_example() {
3160+
doInJPA(this::entityManagerFactory, entityManager -> {
3161+
//tag::hql-cte-recursive-example[]
3162+
List<Tuple> calls = entityManager.createQuery(
3163+
"with paymentConnectedPersons as(" +
3164+
" select a.owner owner " +
3165+
" from Account a where a.id = :startId " +
3166+
" union all" +
3167+
" select a2.owner owner " +
3168+
" from paymentConnectedPersons d " +
3169+
" join Account a on a.owner = d.owner " +
3170+
" join a.payments p " +
3171+
" join Account a2 on a2.owner = p.person" +
3172+
")" +
3173+
"select d.owner " +
3174+
"from paymentConnectedPersons d",
3175+
Tuple.class)
3176+
.setParameter("startId", 123L)
3177+
.getResultList();
3178+
//end::hql-cte-recursive-example[]
3179+
});
3180+
}
3181+
3182+
@Test
3183+
@RequiresDialectFeature( DialectChecks.SupportsRecursiveCtes.class )
3184+
public void test_hql_cte_recursive_search_example() {
3185+
doInJPA(this::entityManagerFactory, entityManager -> {
3186+
//tag::hql-cte-recursive-search-example[]
3187+
List<Tuple> calls = entityManager.createQuery(
3188+
"with paymentConnectedPersons as(" +
3189+
" select a.owner owner " +
3190+
" from Account a where a.id = :startId " +
3191+
" union all" +
3192+
" select a2.owner owner " +
3193+
" from paymentConnectedPersons d " +
3194+
" join Account a on a.owner = d.owner " +
3195+
" join a.payments p " +
3196+
" join Account a2 on a2.owner = p.person" +
3197+
") search breadth first by owner set orderAttr " +
3198+
"select d.owner " +
3199+
"from paymentConnectedPersons d",
3200+
Tuple.class)
3201+
.setParameter("startId", 123L)
3202+
.getResultList();
3203+
//end::hql-cte-recursive-search-example[]
3204+
});
3205+
}
3206+
3207+
@Test
3208+
@RequiresDialectFeature( DialectChecks.SupportsRecursiveCtes.class )
3209+
public void test_hql_cte_recursive_cycle_example() {
3210+
doInJPA(this::entityManagerFactory, entityManager -> {
3211+
//tag::hql-cte-recursive-cycle-example[]
3212+
List<Tuple> calls = entityManager.createQuery(
3213+
"with paymentConnectedPersons as(" +
3214+
" select a.owner owner " +
3215+
" from Account a where a.id = :startId " +
3216+
" union all" +
3217+
" select a2.owner owner " +
3218+
" from paymentConnectedPersons d " +
3219+
" join Account a on a.owner = d.owner " +
3220+
" join a.payments p " +
3221+
" join Account a2 on a2.owner = p.person" +
3222+
") cycle owner set cycleMark " +
3223+
"select d.owner, d.cycleMark " +
3224+
"from paymentConnectedPersons d",
3225+
Tuple.class)
3226+
.setParameter("startId", 123L)
3227+
.getResultList();
3228+
//end::hql-cte-recursive-cycle-example[]
3229+
});
3230+
}
3231+
31363232
@Test
31373233
@RequiresDialectFeature({
31383234
DialectChecks.SupportsSubqueryInOnClause.class,

gradle/databases.gradle

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -155,6 +155,14 @@ ext {
155155
'jdbc.url' : 'jdbc:mysql://' + dbHost + '/hibernate_orm_test',
156156
'connection.init_sql' : ''
157157
],
158+
tidb_ci5 : [
159+
'db.dialect' : 'org.hibernate.dialect.TiDBDialect',
160+
'jdbc.driver': 'com.mysql.jdbc.Driver',
161+
'jdbc.user' : 'root',
162+
'jdbc.pass' : '',
163+
'jdbc.url' : 'jdbc:mysql://' + dbHost + ':4000/test',
164+
'connection.init_sql' : ''
165+
],
158166
postgis : [
159167
'db.dialect' : 'org.hibernate.spatial.dialect.postgis.PostgisPG95Dialect',
160168
'jdbc.driver': 'org.postgresql.Driver',

hibernate-community-dialects/src/main/java/org/hibernate/community/dialect/CUBRIDSqlAstTranslator.java

Lines changed: 0 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -37,16 +37,6 @@ public void visitOffsetFetchClause(QueryPart queryPart) {
3737
renderCombinedLimitClause( queryPart );
3838
}
3939

40-
@Override
41-
protected void renderSearchClause(CteStatement cte) {
42-
// CUBRID does not support this, but it's just a hint anyway
43-
}
44-
45-
@Override
46-
protected void renderCycleClause(CteStatement cte) {
47-
// CUBRID does not support this, but it can be emulated
48-
}
49-
5040
@Override
5141
protected void renderComparison(Expression lhs, ComparisonOperator operator, Expression rhs) {
5242
renderComparisonEmulateIntersect( lhs, operator, rhs );

hibernate-community-dialects/src/main/java/org/hibernate/community/dialect/CacheSqlAstTranslator.java

Lines changed: 0 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -80,16 +80,6 @@ public void visitOffsetFetchClause(QueryPart queryPart) {
8080
}
8181
}
8282

83-
@Override
84-
protected void renderSearchClause(CteStatement cte) {
85-
// Cache does not support this, but it's just a hint anyway
86-
}
87-
88-
@Override
89-
protected void renderCycleClause(CteStatement cte) {
90-
// Cache does not support this, but it can be emulated
91-
}
92-
9383
@Override
9484
protected void renderComparison(Expression lhs, ComparisonOperator operator, Expression rhs) {
9585
renderComparisonEmulateIntersect( lhs, operator, rhs );

hibernate-community-dialects/src/main/java/org/hibernate/community/dialect/CockroachLegacyDialect.java

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -468,6 +468,11 @@ public boolean supportsNonQueryWithCTE() {
468468
return true;
469469
}
470470

471+
@Override
472+
public boolean supportsRecursiveCTE() {
473+
return getVersion().isSameOrAfter( 20, 1 );
474+
}
475+
471476
@Override
472477
public String getNoColumnsInsertString() {
473478
return "default values";

0 commit comments

Comments
 (0)