Skip to content

Commit 4876cd6

Browse files
andygrovealamb
andauthored
User Guide: Add documentation for subquery syntax (#3132)
* Add user guide section on subquery support * Update docs/source/user-guide/sql/subqueries.md Co-authored-by: Andrew Lamb <andrew@nerdnetworks.org> * Update docs/source/user-guide/sql/subqueries.md Co-authored-by: Andrew Lamb <andrew@nerdnetworks.org> * Update docs/source/user-guide/sql/subqueries.md Co-authored-by: Andrew Lamb <andrew@nerdnetworks.org> * prettier Co-authored-by: Andrew Lamb <andrew@nerdnetworks.org>
1 parent 5778ef2 commit 4876cd6

File tree

2 files changed

+99
-0
lines changed

2 files changed

+99
-0
lines changed

docs/source/user-guide/sql/index.rst

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@ SQL Reference
2323

2424
sql_status
2525
select
26+
subqueries
2627
ddl
2728
aggregate_functions
2829
scalar_functions
Lines changed: 98 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,98 @@
1+
<!---
2+
Licensed to the Apache Software Foundation (ASF) under one
3+
or more contributor license agreements. See the NOTICE file
4+
distributed with this work for additional information
5+
regarding copyright ownership. The ASF licenses this file
6+
to you under the Apache License, Version 2.0 (the
7+
"License"); you may not use this file except in compliance
8+
with the License. You may obtain a copy of the License at
9+
10+
http://www.apache.org/licenses/LICENSE-2.0
11+
12+
Unless required by applicable law or agreed to in writing,
13+
software distributed under the License is distributed on an
14+
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
15+
KIND, either express or implied. See the License for the
16+
specific language governing permissions and limitations
17+
under the License.
18+
-->
19+
20+
# Subqueries
21+
22+
DataFusion supports `EXISTS`, `NOT EXISTS`, `IN`, `NOT IN` and Scalar Subqueries.
23+
24+
The examples below are based on the following table.
25+
26+
```sql
27+
select * from x;
28+
+----------+----------+
29+
| column_1 | column_2 |
30+
+----------+----------+
31+
| 1 | 2 |
32+
+----------+----------+
33+
```
34+
35+
## EXISTS
36+
37+
The `EXISTS` syntax can be used to find all rows in a relation where a correlated subquery produces one or more matches
38+
for that row. Only correlated subqueries are supported.
39+
40+
```sql
41+
select * from x y where exists (select * from x where x.column_1 = y.column_1);
42+
+----------+----------+
43+
| column_1 | column_2 |
44+
+----------+----------+
45+
| 1 | 2 |
46+
+----------+----------+
47+
1 row in set.
48+
```
49+
50+
## NOT EXISTS
51+
52+
The `NOT EXISTS` syntax can be used to find all rows in a relation where a correlated subquery produces zero matches
53+
for that row. Only correlated subqueries are supported.
54+
55+
```sql
56+
select * from x y where not exists (select * from x where x.column_1 = y.column_1);
57+
0 rows in set.
58+
```
59+
60+
## IN
61+
62+
The `IN` syntax can be used to find all rows in a relation where a given expression's value can be found in the
63+
results of a correlated subquery.
64+
65+
```sql
66+
select * from x where column_1 in (select column_1 from x);
67+
+----------+----------+
68+
| column_1 | column_2 |
69+
+----------+----------+
70+
| 1 | 2 |
71+
+----------+----------+
72+
1 row in set.
73+
```
74+
75+
## NOT IN
76+
77+
The `NOT IN` syntax can be used to find all rows in a relation where a given expression's value can not be found in the
78+
results of a correlated subquery.
79+
80+
```sql
81+
select * from x where column_1 not in (select column_1 from x);
82+
0 rows in set.
83+
```
84+
85+
## Scalar Subquery
86+
87+
A scalar subquery can be used to produce a single value that can be used in many different contexts in a query. Here
88+
is an example of a filter using a scalar subquery. Only correlated subqueries are supported.
89+
90+
```sql
91+
select * from x y where column_1 < (select sum(column_2) from x where x.column_1 = y.column_1);
92+
+----------+----------+
93+
| column_1 | column_2 |
94+
+----------+----------+
95+
| 1 | 2 |
96+
+----------+----------+
97+
1 row in set.
98+
```

0 commit comments

Comments
 (0)