Skip to content

Commit 642d4fa

Browse files
authored
Merge pull request #1139 from marmphco/recursive-cte
Add support for the WITH clause
2 parents d9da556 + cfa6010 commit 642d4fa

File tree

6 files changed

+302
-5
lines changed

6 files changed

+302
-5
lines changed

Documentation/Index.md

+60
Original file line numberDiff line numberDiff line change
@@ -34,6 +34,7 @@
3434
- [Filter Operators and Functions](#filter-operators-and-functions)
3535
- [Sorting Rows](#sorting-rows)
3636
- [Limiting and Paging Results](#limiting-and-paging-results)
37+
- [Recursive and Hierarchical Queries](#recursive-and-hierarchical-queries)
3738
- [Aggregation](#aggregation)
3839
- [Upserting Rows](#upserting-rows)
3940
- [Updating Rows](#updating-rows)
@@ -1086,6 +1087,65 @@ users.limit(5, offset: 5)
10861087
```
10871088

10881089

1090+
#### Recursive and Hierarchical Queries
1091+
1092+
We can perform a recursive or hierarchical query using a [query's](#queries) `with`
1093+
function.
1094+
1095+
```swift
1096+
// Get the management chain for the manager with id == 8
1097+
1098+
let chain = Table("chain")
1099+
let id = Expression<Int64>("id")
1100+
let managerId = Expression<Int64>("manager_id")
1101+
1102+
let query = managers
1103+
.where(id == 8)
1104+
.union(chain.join(managers, on: chain[managerId] == managers[id])
1105+
1106+
chain.with(chain, recursive: true, as: query)
1107+
// WITH RECURSIVE
1108+
// "chain" AS (
1109+
// SELECT * FROM "managers" WHERE "id" = 8
1110+
// UNION
1111+
// SELECT * from "chain"
1112+
// JOIN "managers" ON "chain"."manager_id" = "managers"."id"
1113+
// )
1114+
// SELECT * FROM "chain"
1115+
```
1116+
1117+
Column names and a materialization hint can optionally be provided.
1118+
1119+
```swift
1120+
// Add a "level" column to the query representing manager's position in the chain
1121+
let level = Expression<Int64>("level")
1122+
1123+
let queryWithLevel =
1124+
managers
1125+
.select(id, managerId, 0)
1126+
.where(id == 8)
1127+
.union(
1128+
chain
1129+
.select(managers[id], managers[manager_id], level + 1)
1130+
.join(managers, on: chain[managerId] == managers[id])
1131+
)
1132+
1133+
chain.with(chain,
1134+
columns: [id, managerId, level],
1135+
recursive: true,
1136+
hint: .materialize,
1137+
as: queryWithLevel)
1138+
// WITH RECURSIVE
1139+
// "chain" ("id", "manager_id", "level") AS MATERIALIZED (
1140+
// SELECT ("id", "manager_id", 0) FROM "managers" WHERE "id" = 8
1141+
// UNION
1142+
// SELECT ("manager"."id", "manager"."manager_id", "level" + 1) FROM "chain"
1143+
// JOIN "managers" ON "chain"."manager_id" = "managers"."id"
1144+
// )
1145+
// SELECT * FROM "chain"
1146+
```
1147+
1148+
10891149
#### Aggregation
10901150

10911151
[Queries](#queries) come with a number of functions that quickly return

SQLite.xcodeproj/project.pbxproj

+10
Original file line numberDiff line numberDiff line change
@@ -130,6 +130,10 @@
130130
49EB68C51F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; };
131131
49EB68C61F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; };
132132
49EB68C71F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; };
133+
997DF2AE287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; };
134+
997DF2AF287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; };
135+
997DF2B0287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; };
136+
997DF2B1287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; };
133137
D4DB368C20C09CFB00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; };
134138
D4DB368D20C09CFC00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; };
135139
D4DB368E20C09CFD00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; };
@@ -260,6 +264,7 @@
260264
3D67B3E51DB2469200A4F4C6 /* libsqlite3.tbd */ = {isa = PBXFileReference; lastKnownFileType = "sourcecode.text-based-dylib-definition"; name = libsqlite3.tbd; path = Platforms/WatchOS.platform/Developer/SDKs/WatchOS3.0.sdk/usr/lib/libsqlite3.tbd; sourceTree = DEVELOPER_DIR; };
261265
3DDC112E26CDBA0200CE369F /* SQLiteObjc.h */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.c.h; name = SQLiteObjc.h; path = ../SQLiteObjc/include/SQLiteObjc.h; sourceTree = "<group>"; };
262266
49EB68C31F7B3CB400D89D40 /* Coding.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = Coding.swift; sourceTree = "<group>"; };
267+
997DF2AD287FC06D00F8DF95 /* Query+with.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = "Query+with.swift"; sourceTree = "<group>"; };
263268
A121AC451CA35C79005A31D1 /* SQLite.framework */ = {isa = PBXFileReference; explicitFileType = wrapper.framework; includeInIndex = 0; path = SQLite.framework; sourceTree = BUILT_PRODUCTS_DIR; };
264269
D4DB368A20C09C9B00D5A58E /* SelectTests.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = SelectTests.swift; sourceTree = "<group>"; };
265270
EE247AD31C3F04ED00AE3E12 /* SQLite.framework */ = {isa = PBXFileReference; explicitFileType = wrapper.framework; includeInIndex = 0; path = SQLite.framework; sourceTree = BUILT_PRODUCTS_DIR; };
@@ -499,6 +504,7 @@
499504
EE247AFE1C3F06E900AE3E12 /* Expression.swift */,
500505
EE247AFF1C3F06E900AE3E12 /* Operators.swift */,
501506
EE247B001C3F06E900AE3E12 /* Query.swift */,
507+
997DF2AD287FC06D00F8DF95 /* Query+with.swift */,
502508
EE247B011C3F06E900AE3E12 /* Schema.swift */,
503509
EE247B021C3F06E900AE3E12 /* Setter.swift */,
504510
49EB68C31F7B3CB400D89D40 /* Coding.swift */,
@@ -862,6 +868,7 @@
862868
19A17FF4A10B44D3937C8CAC /* Errors.swift in Sources */,
863869
19A1737286A74F3CF7412906 /* DateAndTimeFunctions.swift in Sources */,
864870
19A17073552293CA063BEA66 /* Result.swift in Sources */,
871+
997DF2B0287FC06D00F8DF95 /* Query+with.swift in Sources */,
865872
19A179B59450FE7C4811AB8A /* Connection+Aggregation.swift in Sources */,
866873
);
867874
runOnlyForDeploymentPostprocessing = 0;
@@ -904,6 +911,7 @@
904911
files = (
905912
3D67B3F91DB246E700A4F4C6 /* SQLiteObjc.m in Sources */,
906913
49EB68C71F7B3CB400D89D40 /* Coding.swift in Sources */,
914+
997DF2B1287FC06D00F8DF95 /* Query+with.swift in Sources */,
907915
3D67B3F71DB246D700A4F4C6 /* Foundation.swift in Sources */,
908916
3D67B3F81DB246D700A4F4C6 /* Helpers.swift in Sources */,
909917
3D67B3E91DB246D100A4F4C6 /* Statement.swift in Sources */,
@@ -959,6 +967,7 @@
959967
19A1792C0520D4E83C2EB075 /* Errors.swift in Sources */,
960968
19A17E29278A12BC4F542506 /* DateAndTimeFunctions.swift in Sources */,
961969
19A173EFEF0B3BD0B3ED406C /* Result.swift in Sources */,
970+
997DF2AE287FC06D00F8DF95 /* Query+with.swift in Sources */,
962971
19A176376CB6A94759F7980A /* Connection+Aggregation.swift in Sources */,
963972
);
964973
runOnlyForDeploymentPostprocessing = 0;
@@ -1024,6 +1033,7 @@
10241033
19A17490543609FCED53CACC /* Errors.swift in Sources */,
10251034
19A17152E32A9585831E3FE0 /* DateAndTimeFunctions.swift in Sources */,
10261035
19A17F1B3F0A3C96B5ED6D64 /* Result.swift in Sources */,
1036+
997DF2AF287FC06D00F8DF95 /* Query+with.swift in Sources */,
10271037
19A170ACC97B19730FB7BA4D /* Connection+Aggregation.swift in Sources */,
10281038
);
10291039
runOnlyForDeploymentPostprocessing = 0;

Sources/SQLite/Typed/Query+with.swift

+117
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,117 @@
1+
//
2+
// SQLite.swift
3+
// https://github.com/stephencelis/SQLite.swift
4+
// Copyright © 2014-2015 Stephen Celis.
5+
//
6+
// Permission is hereby granted, free of charge, to any person obtaining a copy
7+
// of this software and associated documentation files (the "Software"), to deal
8+
// in the Software without restriction, including without limitation the rights
9+
// to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
10+
// copies of the Software, and to permit persons to whom the Software is
11+
// furnished to do so, subject to the following conditions:
12+
//
13+
// The above copyright notice and this permission notice shall be included in
14+
// all copies or substantial portions of the Software.
15+
//
16+
// THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
17+
// IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
18+
// FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
19+
// AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
20+
// LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
21+
// OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
22+
// THE SOFTWARE.
23+
//
24+
import Foundation
25+
26+
extension QueryType {
27+
28+
/// Sets a `WITH` clause on the query.
29+
///
30+
/// let users = Table("users")
31+
/// let id = Expression<String>("email")
32+
/// let name = Expression<String?>("name")
33+
///
34+
/// let userNames = Table("user_names")
35+
/// userCategories.with(userNames, as: users.select(name))
36+
/// // WITH "user_names" as (SELECT "name" FROM "users") SELECT * FROM "user_names"
37+
///
38+
/// - Parameters:
39+
///
40+
/// - alias: A name to assign to the table expression.
41+
///
42+
/// - recursive: Whether to evaluate the expression recursively.
43+
///
44+
/// - hint: Provides a hint to the query planner for how the expression should be implemented.
45+
///
46+
/// - subquery: A query that generates the rows for the table expression.
47+
///
48+
/// - Returns: A query with the given `ORDER BY` clause applied.
49+
public func with(_ alias: Table, columns: [Expressible]? = nil, recursive: Bool = false,
50+
hint: MaterializationHint? = nil, as subquery: QueryType) -> Self {
51+
var query = self
52+
let clause = WithClauses.Clause(alias: alias, columns: columns, hint: hint, query: subquery)
53+
query.clauses.with.recursive = query.clauses.with.recursive || recursive
54+
query.clauses.with.clauses.append(clause)
55+
return query
56+
}
57+
58+
/// self.clauses.with transformed to an Expressible
59+
var withClause: Expressible? {
60+
guard !clauses.with.clauses.isEmpty else {
61+
return nil
62+
}
63+
64+
let innerClauses = ", ".join(clauses.with.clauses.map { (clause) in
65+
let hintExpr: Expression<Void>?
66+
if let hint = clause.hint {
67+
hintExpr = Expression<Void>(literal: hint.rawValue)
68+
} else {
69+
hintExpr = nil
70+
}
71+
72+
let columnExpr: Expression<Void>?
73+
if let columns = clause.columns {
74+
columnExpr = "".wrap(", ".join(columns))
75+
} else {
76+
columnExpr = nil
77+
}
78+
79+
let expressions: [Expressible?] = [
80+
clause.alias.tableName(),
81+
columnExpr,
82+
Expression<Void>(literal: "AS"),
83+
hintExpr,
84+
"".wrap(clause.query) as Expression<Void>
85+
]
86+
87+
return " ".join(expressions.compactMap { $0 })
88+
})
89+
90+
return " ".join([
91+
Expression<Void>(literal: clauses.with.recursive ? "WITH RECURSIVE" : "WITH"),
92+
innerClauses
93+
])
94+
}
95+
}
96+
97+
/// Materialization hints for `WITH` clause
98+
public enum MaterializationHint: String {
99+
100+
case materialized = "MATERIALIZED"
101+
102+
case notMaterialized = "NOT MATERIALIZED"
103+
}
104+
105+
struct WithClauses {
106+
struct Clause {
107+
var alias: Table
108+
var columns: [Expressible]?
109+
var hint: MaterializationHint?
110+
var query: QueryType
111+
}
112+
/// The `RECURSIVE` flag is applied to the entire `WITH` clause
113+
var recursive: Bool = false
114+
115+
/// Each `WITH` clause may have multiple subclauses
116+
var clauses: [Clause] = []
117+
}

Sources/SQLite/Typed/Query.swift

+10-5
Original file line numberDiff line numberDiff line change
@@ -193,12 +193,14 @@ extension QueryType {
193193
///
194194
/// - Parameters:
195195
///
196+
/// - all: If false, duplicate rows are removed from the result.
197+
///
196198
/// - table: A query representing the other table.
197199
///
198200
/// - Returns: A query with the given `UNION` clause applied.
199-
public func union(_ table: QueryType) -> Self {
201+
public func union(all: Bool = false, _ table: QueryType) -> Self {
200202
var query = self
201-
query.clauses.union.append(table)
203+
query.clauses.union.append((all, table))
202204
return query
203205
}
204206

@@ -596,9 +598,9 @@ extension QueryType {
596598
return nil
597599
}
598600

599-
return " ".join(clauses.union.map { query in
601+
return " ".join(clauses.union.map { (all, query) in
600602
" ".join([
601-
Expression<Void>(literal: "UNION"),
603+
Expression<Void>(literal: all ? "UNION ALL" : "UNION"),
602604
query
603605
])
604606
})
@@ -856,6 +858,7 @@ extension QueryType {
856858

857859
public var expression: Expression<Void> {
858860
let clauses: [Expressible?] = [
861+
withClause,
859862
selectClause,
860863
joinClause,
861864
whereClause,
@@ -1251,7 +1254,9 @@ public struct QueryClauses {
12511254

12521255
var limit: (length: Int, offset: Int?)?
12531256

1254-
var union = [QueryType]()
1257+
var union = [(all: Bool, table: QueryType)]()
1258+
1259+
var with = WithClauses()
12551260

12561261
fileprivate init(_ name: String, alias: String?, database: String?) {
12571262
from = (name, alias, database)

Tests/SQLiteTests/QueryIntegrationTests.swift

+41
Original file line numberDiff line numberDiff line change
@@ -230,6 +230,47 @@ class QueryIntegrationTests: SQLiteTestCase {
230230
let result = Array(try db.prepare(users.select(email).order(Expression<Int>.random()).limit(1)))
231231
XCTAssertEqual(1, result.count)
232232
}
233+
234+
func test_with_recursive() {
235+
let nodes = Table("nodes")
236+
let id = Expression<Int64>("id")
237+
let parent = Expression<Int64?>("parent")
238+
let value = Expression<Int64>("value")
239+
240+
try! db.run(nodes.create { builder in
241+
builder.column(id)
242+
builder.column(parent)
243+
builder.column(value)
244+
})
245+
246+
try! db.run(nodes.insertMany([
247+
[id <- 0, parent <- nil, value <- 2],
248+
[id <- 1, parent <- 0, value <- 4],
249+
[id <- 2, parent <- 0, value <- 9],
250+
[id <- 3, parent <- 2, value <- 8],
251+
[id <- 4, parent <- 2, value <- 7],
252+
[id <- 5, parent <- 4, value <- 3]
253+
]))
254+
255+
// Compute the sum of the values of node 5 and its ancestors
256+
let ancestors = Table("ancestors")
257+
let sum = try! db.scalar(
258+
ancestors
259+
.select(value.sum)
260+
.with(ancestors,
261+
columns: [id, parent, value],
262+
recursive: true,
263+
as: nodes
264+
.where(id == 5)
265+
.union(all: true,
266+
nodes.join(ancestors, on: nodes[id] == ancestors[parent])
267+
.select(nodes[id], nodes[parent], nodes[value])
268+
)
269+
)
270+
)
271+
272+
XCTAssertEqual(21, sum)
273+
}
233274
}
234275

235276
extension Connection {

0 commit comments

Comments
 (0)