Skip to content

Commit a1cb48c

Browse files
committed
Documentation
1 parent e0f2519 commit a1cb48c

File tree

3 files changed

+183
-105
lines changed

3 files changed

+183
-105
lines changed

CHANGELOG.md

+12-1
Original file line numberDiff line numberDiff line change
@@ -6,10 +6,19 @@ This log will detail notable changes to MyBatis Dynamic SQL. Full details are av
66

77
GitHub milestone: [https://github.com/mybatis/mybatis-dynamic-sql/issues?q=milestone%3A1.3.0+](https://github.com/mybatis/mybatis-dynamic-sql/issues?q=milestone%3A1.3.0+)
88

9+
### Release Themes
10+
11+
The major themes of this release include the following:
12+
13+
1. Add support for subqueries in select statements - both in a from clause and a join clause
14+
1. Continue to refine the Kotlin DSL. Most changes to the Kotlin DSL are internal and should be source code
15+
compatible with existing code. There is one breaking change detailed below.
16+
1. Remove deprecated code from prior releases
17+
918
### Breaking Change for Kotlin
1019

1120
In this release the Kotlin support for `select` and `count` statements has been refactored. This will not impact code
12-
created by MyBatis generator. It will have an impact on Spring users as well as MyBatis users that coded joins or
21+
created by MyBatis generator. It will have an impact on Spring/Kotlin users as well as MyBatis users that coded joins or
1322
other queries directly in Kotlin. The difference is that the `from` clause has been moved inside the lambda for select
1423
and count statements.
1524

@@ -37,6 +46,8 @@ Kotlin DSL.
3746
- Added the capability to generate a camel cased alias for a column ([#272](https://github.com/mybatis/mybatis-dynamic-sql/issues/272))
3847
- Added sub-query support for "from" clauses in a select statement ([#282](https://github.com/mybatis/mybatis-dynamic-sql/pull/282))
3948
- Added Kotlin DSL updates to support sub-queries in select statements, where clauses, and insert statements ([#282](https://github.com/mybatis/mybatis-dynamic-sql/pull/282))
49+
- Added sub-query support for "join" clauses in a select statement
50+
4051

4152
## Release 1.2.1 - September 29, 2020
4253

src/main/kotlin/org/mybatis/dynamic/sql/util/kotlin/KotlinModelBuilderFunctions.kt

+1-1
Original file line numberDiff line numberDiff line change
@@ -56,7 +56,7 @@ object KotlinModelBuilderFunctions {
5656
}
5757

5858
fun <T> BatchInsertDSL.IntoGatherer<T>.into(table: SqlTable, completer: BatchInsertCompleter<T>) =
59-
into(table).also(completer).build()
59+
into(table).apply(completer).build()
6060

6161
fun <T> InsertDSL.IntoGatherer<T>.into(table: SqlTable, completer: InsertCompleter<T>) =
6262
into(table).apply(completer).build()

src/site/markdown/docs/subQueries.md

+170-103
Original file line numberDiff line numberDiff line change
@@ -5,6 +5,113 @@ The library currently supports subqueries in the following areas:
55
1. In certain insert statements
66
1. In update statements
77
1. In the "from" clause of a select statement
8+
1. In join clauses of a select statement
9+
10+
Before we show examples of subqueries, it is important to understand how the library generates and applies
11+
table qualifiers in select statements. We'll cover that first.
12+
13+
## Table Qualifiers in Select Statements
14+
15+
The library attempts to automatically calculate table qualifiers. If a table qualifier is specified,
16+
the library will automatically render the table qualifier on all columns associated with the
17+
table. For example with the following query:
18+
19+
```java
20+
SelectStatementProvider selectStatement =
21+
select(id, animalName)
22+
.from(animalData, "ad")
23+
.build()
24+
.render(RenderingStrategies.MYBATIS3);
25+
```
26+
27+
The library will render SQL as:
28+
29+
```sql
30+
select ad.id, ad.animal_name
31+
from AnimalData ad
32+
```
33+
34+
Notice that the table qualifier `ad` is automatically applied to columns in the select list.
35+
36+
In the case of join queries the table qualifier specified, or if not specified the table name
37+
itself, will be used as the table qualifier. However, this function is disabled for joins on subqueries.
38+
39+
With subqueries, it is important to understand the limits of automatic table qualifiers. The rules are
40+
as follows:
41+
42+
1. The scope of automatic table qualifiers is limited to a single select statement. For subqueries, the outer
43+
query has a different scope than the subquery.
44+
1. A qualifier can be applied to a subquery, but that qualifier is not automatically applied to
45+
any column
46+
47+
As an example, consider the following query:
48+
49+
```java
50+
DerivedColumn<Integer> rowNum = DerivedColumn.of("rownum()");
51+
52+
SelectStatementProvider selectStatement =
53+
select(animalName, rowNum)
54+
.from(
55+
select(id, animalName)
56+
.from(animalData, "a")
57+
.where(id, isLessThan(22))
58+
.orderBy(animalName.descending()),
59+
"b"
60+
)
61+
.where(rowNum, isLessThan(5))
62+
.and(animalName, isLike("%a%"))
63+
.build()
64+
.render(RenderingStrategies.MYBATIS3);
65+
```
66+
67+
The rendered SQL will be as follows:
68+
69+
```sql
70+
select animal_name, rownum()
71+
from (select a.id, a.animal_name
72+
from AnimalDate a
73+
where id < #{parameters.p1}
74+
order by animal_name desc) b
75+
where rownum() < #{parameters.p2}
76+
and animal_name like #{parameters.p3}
77+
```
78+
79+
Notice that the qualifier `a` is automatically applied to columns in the subquery and that the
80+
qualifier `b` is not applied anywhere.
81+
82+
If your query requires the subquery qualifier to be applied to columns in the outer select list,
83+
you can manually apply the qualifier to columns as follows:
84+
85+
```java
86+
DerivedColumn<Integer> rowNum = DerivedColumn.of("rownum()");
87+
88+
SelectStatementProvider selectStatement =
89+
select(animalName.qualifiedWith("b"), rowNum)
90+
.from(
91+
select(id, animalName)
92+
.from(animalData, "a")
93+
.where(id, isLessThan(22))
94+
.orderBy(animalName.descending()),
95+
"b"
96+
)
97+
.where(rowNum, isLessThan(5))
98+
.and(animalName.qualifiedWith("b"), isLike("%a%"))
99+
.build()
100+
.render(RenderingStrategies.MYBATIS3);
101+
```
102+
103+
In this case, we have manually applied the qualifier `b` to columns in the outer query. The
104+
rendered SQL looks like this:
105+
106+
```sql
107+
select b.animal_name, rownum()
108+
from (select a.id, a.animal_name
109+
from AnimalDate a
110+
where id < #{parameters.p1}
111+
order by animal_name desc) b
112+
where rownum() < #{parameters.p2}
113+
and b.animal_name like #{parameters.p3}
114+
```
8115

9116
## Subqueries in Where Conditions
10117
The library support subqueries in the following where conditions:
@@ -136,109 +243,6 @@ SelectStatementProvider selectStatement =
136243
Notice the use of a `DerivedColumn` to easily specify a function like `rownum()` that can be
137244
used both in the select list and in a where condition.
138245

139-
### Table Qualifiers with Subqueries
140-
141-
The library attempts to automatically calculate table qualifiers. If a table qualifier is specified,
142-
the library will automatically render the table qualifier on all columns associated with the
143-
table. For example with the following query:
144-
145-
```java
146-
SelectStatementProvider selectStatement =
147-
select(id, animalName)
148-
.from(animalData, "ad")
149-
.build()
150-
.render(RenderingStrategies.MYBATIS3);
151-
```
152-
153-
The library will render SQL as:
154-
155-
```sql
156-
select ad.id, ad.animal_name
157-
from AnimalData ad
158-
```
159-
160-
Notice that the table qualifier `ad` is automatically applied to columns in the select list.
161-
162-
In the case of join queries the table qualifier specified, or if not specified the table name
163-
itself, will be used as the table qualifier.
164-
165-
With subqueries, it is important to understand the limits of automatic table qualifiers. The rules are
166-
as follows:
167-
168-
1. The scope of automatic table qualifiers is limited to a single select statement. For subqueries, the outer
169-
query has a different scope than the subquery.
170-
1. A qualifier can be applied to a subquery as a whole, but that qualifier is not automatically applied to
171-
any column
172-
173-
As an example, consider the following query:
174-
175-
```java
176-
DerivedColumn<Integer> rowNum = DerivedColumn.of("rownum()");
177-
178-
SelectStatementProvider selectStatement =
179-
select(animalName, rowNum)
180-
.from(
181-
select(id, animalName)
182-
.from(animalData, "a")
183-
.where(id, isLessThan(22))
184-
.orderBy(animalName.descending()),
185-
"b"
186-
)
187-
.where(rowNum, isLessThan(5))
188-
.and(animalName, isLike("%a%"))
189-
.build()
190-
.render(RenderingStrategies.MYBATIS3);
191-
```
192-
193-
The rendered SQL will be as follows:
194-
195-
```sql
196-
select animal_name, rownum()
197-
from (select a.id, a.animal_name
198-
from AnimalDate a
199-
where id < #{parameters.p1}
200-
order by animal_name desc) b
201-
where rownum() < #{parameters.p2}
202-
and animal_name like #{parameters.p3}
203-
```
204-
205-
Notice that the qualifier `a` is automatically applied to columns in the subquery and that the
206-
qualifier `b` is not applied anywhere.
207-
208-
If your query requires the subquery qualifier to be applied to columns in the outer select list,
209-
you can manually apply the qualifier to columns as follows:
210-
211-
```java
212-
DerivedColumn<Integer> rowNum = DerivedColumn.of("rownum()");
213-
214-
SelectStatementProvider selectStatement =
215-
select(animalName.qualifiedWith("b"), rowNum)
216-
.from(
217-
select(id, animalName)
218-
.from(animalData, "a")
219-
.where(id, isLessThan(22))
220-
.orderBy(animalName.descending()),
221-
"b"
222-
)
223-
.where(rowNum, isLessThan(5))
224-
.and(animalName.qualifiedWith("b"), isLike("%a%"))
225-
.build()
226-
.render(RenderingStrategies.MYBATIS3);
227-
```
228-
229-
In this case, we have manually applied the qualifier `b` to columns in the outer query. The
230-
rendered SQL looks like this:
231-
232-
```sql
233-
select b.animal_name, rownum()
234-
from (select a.id, a.animal_name
235-
from AnimalDate a
236-
where id < #{parameters.p1}
237-
order by animal_name desc) b
238-
where rownum() < #{parameters.p2}
239-
and b.animal_name like #{parameters.p3}
240-
```
241-
242246
### Kotlin Support
243247

244248
The library includes a Kotlin builder for subqueries that integrates with the select DSL. You
@@ -280,3 +284,66 @@ val selectStatement =
280284

281285
In this case the `a` qualifier is used in the context of the inner select statement and
282286
the `b` qualifier is applied to the subquery as a whole.
287+
288+
## Subqueries in Join Clauses
289+
The library supports subqueries in "join" clauses similarly to subqueries in "from" clauses. For example:
290+
291+
```java
292+
SelectStatementProvider selectStatement = select(orderMaster.orderId, orderMaster.orderDate,
293+
orderDetail.lineNumber, orderDetail.description, orderDetail.quantity)
294+
.from(orderMaster, "om")
295+
.join(
296+
select(orderDetail.orderId, orderDetail.lineNumber, orderDetail.description, orderDetail.quantity)
297+
.from(orderDetail),
298+
"od")
299+
.on(orderMaster.orderId, equalTo(orderDetail.orderId.qualifiedWith("od")))
300+
.build()
301+
.render(RenderingStrategies.MYBATIS3);
302+
```
303+
304+
This is rendered as:
305+
306+
```sql
307+
select om.order_id, om.order_date, line_number, description, quantity
308+
from OrderMaster om
309+
join (select order_id, line_number, description, quantity from OrderDetail) od
310+
on om.order_id = od.order_id
311+
```
312+
313+
Notice that the subquery is aliased with "od", but that alias is not automatically applied so it must
314+
be specified when required. If in doubt, specify the alias with the `qualifiedBy` method.
315+
316+
### Kotlin Support
317+
The Kotlin select build supports subqueries in joins as follows:
318+
319+
```kotlin
320+
val selectStatement = select(OrderLine.orderId, OrderLine.quantity,
321+
ItemMaster.itemId.qualifiedWith("im"), ItemMaster.description) {
322+
from(OrderMaster, "om")
323+
join(OrderLine, "ol") {
324+
on(OrderMaster.orderId, equalTo(OrderLine.orderId))
325+
}
326+
leftJoin({
327+
select(ItemMaster.allColumns()) {
328+
from(ItemMaster)
329+
}
330+
+ "im"
331+
}) {
332+
on(OrderLine.itemId, equalTo(ItemMaster.itemId.qualifiedWith("im")))
333+
}
334+
orderBy(OrderLine.orderId, ItemMaster.itemId)
335+
}
336+
```
337+
338+
This is rendered as:
339+
340+
```sql
341+
select ol.order_id, ol.quantity, im.item_id, description
342+
from OrderMaster om join OrderLine ol on om.order_id = ol.order_id
343+
left join (select * from ItemMaster) im on ol.item_id = im.item_id
344+
order by order_id, item_id
345+
```
346+
347+
Notice again that subquery qualifiers must be specified when needed. Also note that the Kotlin join methods accept
348+
two lambda functions - one for the subquery and one for the join specification. Only the join specification can
349+
be outside the parenthesis of the join methods.

0 commit comments

Comments
 (0)