-
-
Notifications
You must be signed in to change notification settings - Fork 1.6k
Add support for the WITH clause #1139
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Changes from 1 commit
12e2166
03b5688
76d34dd
bdacf4d
ced1851
ed43285
0dfc7b0
cfa6010
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
The `WITH` clause provides the ability to do hierarchical or recursive queries of tree and graph-like data. See https://www.sqlite.org/lang_with.html. **Details** - Add `all` parameter to `QueryType.union` to allow `UNION ALL` to be used in a query. I opted to add the parameter to the start of the list so that it does not dangle at the end when the union's query is long: ```swift users.union(all: true, posts.join(users, on: users[id] == posts[userId])) // It's a little easier to read than: users.union(posts.join(users, on: users[id] == posts[userId]), all: true) ``` - Add `with` function to `QueryType`. This function adds a `WITH` clause to a query. The function may be called multiple times to add multiple clauses to a query. If multiple clauses are added to the query with conflicting `recursive` parameters, the whole `WITH` clause will be considered recursive. Like the `union` function, I put the `subquery` parameter at the end so that the `recursive` and `materializationHint` options don't dangle at the end of a long query. ```swift let users = Table("users") let users = Table("posts") let first = Table("first") let second = Table("second") first.with(first, recursive: true as: users).with(second, recursive: false, as: posts) // WITH RECURSIVE "first" AS (SELECT * from users), "second" AS (SELECT * from posts) SELECT * from "first" ```
- Loading branch information
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -193,12 +193,14 @@ extension QueryType { | |
| /// | ||
| /// - Parameters: | ||
| /// | ||
| /// - all: If false, duplicate rows are removed from the result. | ||
| /// | ||
| /// - table: A query representing the other table. | ||
| /// | ||
| /// - Returns: A query with the given `UNION` clause applied. | ||
| public func union(_ table: QueryType) -> Self { | ||
| public func union(all: Bool = false, _ table: QueryType) -> Self { | ||
| var query = self | ||
| query.clauses.union.append(table) | ||
| query.clauses.union.append((all, table)) | ||
| return query | ||
| } | ||
|
|
||
|
|
@@ -496,6 +498,37 @@ extension QueryType { | |
| query.clauses.limit = length.map { ($0, offset) } | ||
| return query | ||
| } | ||
|
|
||
| // MARK: WITH | ||
|
|
||
| /// Sets a `WITH` clause on the query. | ||
| /// | ||
| /// let users = Table("users") | ||
| /// let id = Expression<String>("email") | ||
| /// let name = Expression<String?>("name") | ||
| /// | ||
| /// let userNames = Table("user_names") | ||
| /// userCategories.with(userNames, as: users.select(name)) | ||
| /// // WITH "user_names" as (SELECT "name" FROM "users") SELECT * FROM "user_names" | ||
| /// | ||
| /// - Parameters: | ||
| /// | ||
| /// - alias: A name to assign to the table expression. | ||
| /// | ||
| /// - recursive: Whether to evaluate the expression recursively. | ||
| /// | ||
| /// - materializationHint: Provides a hint to the query planner for how the expression should be implemented. | ||
| /// | ||
| /// - subquery: A query that generates the rows for the table expression. | ||
| /// | ||
| /// - Returns: A query with the given `ORDER BY` clause applied. | ||
| public func with(_ alias: Table, columns: [Expressible]? = nil, recursive: Bool = false, materializationHint: MaterializationHint? = nil, as subquery: QueryType) -> Self { | ||
| var query = self | ||
| let clause = WithClauses.Clause(alias: alias, columns: columns, materializationHint: materializationHint, query: subquery) | ||
| query.clauses.with.recursive = query.clauses.with.recursive || recursive | ||
| query.clauses.with.clauses.append(clause) | ||
| return query | ||
| } | ||
|
|
||
| // MARK: - Clauses | ||
| // | ||
|
|
@@ -596,13 +629,50 @@ extension QueryType { | |
| return nil | ||
| } | ||
|
|
||
| return " ".join(clauses.union.map { query in | ||
| return " ".join(clauses.union.map { (all, query) in | ||
| " ".join([ | ||
| Expression<Void>(literal: "UNION"), | ||
| Expression<Void>(literal: all ? "UNION ALL" : "UNION"), | ||
| query | ||
| ]) | ||
| }) | ||
| } | ||
|
|
||
| fileprivate var withClause: Expressible? { | ||
| guard !clauses.with.clauses.isEmpty else { | ||
| return nil | ||
| } | ||
|
|
||
| let innerClauses = ", ".join(clauses.with.clauses.map { (clause) in | ||
| let hintExpr: Expression<Void>? | ||
| if let hint = clause.materializationHint { | ||
| hintExpr = Expression<Void>(literal: hint.rawValue) | ||
| } else { | ||
| hintExpr = nil | ||
| } | ||
|
|
||
| let columnExpr: Expression<Void>? | ||
| if let columns = clause.columns { | ||
| columnExpr = "".wrap(", ".join(columns)) | ||
| } else { | ||
| columnExpr = nil | ||
| } | ||
|
|
||
| let expressions: [Expressible?] = [ | ||
| clause.alias.tableName(), | ||
| columnExpr, | ||
| Expression<Void>(literal: "AS"), | ||
| hintExpr, | ||
| "".wrap(clause.query) as Expression<Void> | ||
| ] | ||
|
|
||
| return " ".join(expressions.compactMap { $0 }) | ||
| }) | ||
|
|
||
| return " ".join([ | ||
| Expression<Void>(literal: clauses.with.recursive ? "WITH RECURSIVE" : "WITH"), | ||
| innerClauses | ||
| ]) | ||
| } | ||
|
|
||
| // MARK: - | ||
|
|
||
|
|
@@ -856,6 +926,7 @@ extension QueryType { | |
|
|
||
| public var expression: Expression<Void> { | ||
| let clauses: [Expressible?] = [ | ||
| withClause, | ||
| selectClause, | ||
| joinClause, | ||
| whereClause, | ||
|
|
@@ -1233,8 +1304,30 @@ public enum OnConflict: String { | |
|
|
||
| } | ||
|
|
||
| /// Materialization hints for `WITH` clause | ||
| public enum MaterializationHint: String { | ||
|
|
||
| case materialized = "MATERIALIZED" | ||
|
|
||
| case notMaterialized = "NOT MATERIALIZED" | ||
| } | ||
|
|
||
| // MARK: - Private | ||
|
|
||
| struct WithClauses { | ||
|
||
| struct Clause { | ||
| var alias: Table | ||
| var columns: [Expressible]? | ||
| var materializationHint: MaterializationHint? | ||
| var query: QueryType | ||
| } | ||
| /// The `RECURSIVE` flag is applied to the entire `WITH` clause | ||
| var recursive: Bool = false | ||
|
|
||
| /// Each `WITH` clause may have multiple subclauses | ||
| var clauses: [Clause] = [] | ||
| } | ||
|
|
||
| public struct QueryClauses { | ||
|
|
||
| var select = (distinct: false, columns: [Expression<Void>(literal: "*") as Expressible]) | ||
|
|
@@ -1251,7 +1344,9 @@ public struct QueryClauses { | |
|
|
||
| var limit: (length: Int, offset: Int?)? | ||
|
|
||
| var union = [QueryType]() | ||
| var union = [(all: Bool, table: QueryType)]() | ||
|
|
||
| var with = WithClauses() | ||
|
|
||
| fileprivate init(_ name: String, alias: String?, database: String?) { | ||
| from = (name, alias, database) | ||
|
|
||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -58,6 +58,11 @@ class QueryTests: XCTestCase { | |
| func test_selectDistinct_withStar_compilesSelectClause() { | ||
| assertSQL("SELECT DISTINCT * FROM \"users\"", users.select(distinct: *)) | ||
| } | ||
|
|
||
| func test_union_compilesUnionClause() { | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. split:
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I split the tests in cfa6010. I kept the names in the form |
||
| assertSQL("SELECT * FROM \"users\" UNION SELECT * FROM \"posts\"", users.union(posts)) | ||
| assertSQL("SELECT * FROM \"users\" UNION ALL SELECT * FROM \"posts\"", users.union(all: true, posts)) | ||
| } | ||
|
|
||
| func test_join_compilesJoinClause() { | ||
| assertSQL( | ||
|
|
@@ -219,6 +224,61 @@ class QueryTests: XCTestCase { | |
| users.join(managers, on: managers[id] == users[managerId]) | ||
| ) | ||
| } | ||
|
|
||
| func test_with_compilesWithClause() { | ||
| let temp = Table("temp") | ||
|
|
||
| assertSQL("WITH \"temp\" AS (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, as: users)) | ||
| } | ||
|
|
||
| func test_with_recursive_compilesWithClause() { | ||
|
||
| let temp = Table("temp") | ||
|
|
||
| assertSQL("WITH RECURSIVE \"temp\" AS (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, recursive: true, as: users)) | ||
|
|
||
| assertSQL("WITH \"temp\" AS (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, recursive: false, as: users)) | ||
| } | ||
|
|
||
| func test_with_materialization_compilesWithClause() { | ||
|
||
| let temp = Table("temp") | ||
|
|
||
| assertSQL("WITH \"temp\" AS MATERIALIZED (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, materializationHint: .materialized, as: users)) | ||
|
|
||
| assertSQL("WITH \"temp\" AS NOT MATERIALIZED (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, materializationHint: .notMaterialized, as: users)) | ||
| } | ||
|
|
||
| func test_with_columns_compilesWithClause() { | ||
| let temp = Table("temp") | ||
|
|
||
| assertSQL("WITH \"temp\" (\"id\", \"email\") AS (SELECT * FROM \"users\") SELECT * FROM \"temp\"", | ||
| temp.with(temp, columns: [id, email], recursive: false, materializationHint: nil, as: users)) | ||
| } | ||
|
|
||
| func test_with_multiple_compilesWithClause() { | ||
| let temp = Table("temp") | ||
| let second = Table("second") | ||
| let third = Table("third") | ||
|
|
||
| let query = temp | ||
| .with(temp, recursive: true, as: users) | ||
| .with(second, recursive: true, as: posts) | ||
| .with(third, materializationHint: .materialized, as:categories) | ||
|
|
||
| assertSQL( | ||
| """ | ||
| WITH RECURSIVE \"temp\" AS (SELECT * FROM \"users\"), | ||
| \"second\" AS (SELECT * FROM \"posts\"), | ||
| \"third\" AS MATERIALIZED (SELECT * FROM \"categories\") | ||
| SELECT * FROM \"temp\" | ||
| """.replacingOccurrences(of: "\n", with: ""), | ||
| query | ||
| ) | ||
| } | ||
|
|
||
| func test_insert_compilesInsertExpression() { | ||
| assertSQL( | ||
|
|
||
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I agree that putting
allin front of the parameter list is clearer here (and mimics the SQL), but as you say this will break API compatibility, so we'll have to release it as0.14.