diff --git a/Documentation/Index.md b/Documentation/Index.md index e28b24bb..7a9a390f 100644 --- a/Documentation/Index.md +++ b/Documentation/Index.md @@ -34,6 +34,7 @@ - [Filter Operators and Functions](#filter-operators-and-functions) - [Sorting Rows](#sorting-rows) - [Limiting and Paging Results](#limiting-and-paging-results) + - [Recursive and Hierarchical Queries](#recursive-and-hierarchical-queries) - [Aggregation](#aggregation) - [Upserting Rows](#upserting-rows) - [Updating Rows](#updating-rows) @@ -1086,6 +1087,65 @@ users.limit(5, offset: 5) ``` +#### Recursive and Hierarchical Queries + +We can perform a recursive or hierarchical query using a [query's](#queries) `with` +function. + +```swift +// Get the management chain for the manager with id == 8 + +let chain = Table("chain") +let id = Expression("id") +let managerId = Expression("manager_id") + +let query = managers + .where(id == 8) + .union(chain.join(managers, on: chain[managerId] == managers[id]) + +chain.with(chain, recursive: true, as: query) +// WITH RECURSIVE +// "chain" AS ( +// SELECT * FROM "managers" WHERE "id" = 8 +// UNION +// SELECT * from "chain" +// JOIN "managers" ON "chain"."manager_id" = "managers"."id" +// ) +// SELECT * FROM "chain" +``` + +Column names and a materialization hint can optionally be provided. + +```swift +// Add a "level" column to the query representing manager's position in the chain +let level = Expression("level") + +let queryWithLevel = + managers + .select(id, managerId, 0) + .where(id == 8) + .union( + chain + .select(managers[id], managers[manager_id], level + 1) + .join(managers, on: chain[managerId] == managers[id]) + ) + +chain.with(chain, + columns: [id, managerId, level], + recursive: true, + hint: .materialize, + as: queryWithLevel) +// WITH RECURSIVE +// "chain" ("id", "manager_id", "level") AS MATERIALIZED ( +// SELECT ("id", "manager_id", 0) FROM "managers" WHERE "id" = 8 +// UNION +// SELECT ("manager"."id", "manager"."manager_id", "level" + 1) FROM "chain" +// JOIN "managers" ON "chain"."manager_id" = "managers"."id" +// ) +// SELECT * FROM "chain" +``` + + #### Aggregation [Queries](#queries) come with a number of functions that quickly return diff --git a/SQLite.xcodeproj/project.pbxproj b/SQLite.xcodeproj/project.pbxproj index 61c2773a..fc38e5e9 100644 --- a/SQLite.xcodeproj/project.pbxproj +++ b/SQLite.xcodeproj/project.pbxproj @@ -130,6 +130,10 @@ 49EB68C51F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; }; 49EB68C61F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; }; 49EB68C71F7B3CB400D89D40 /* Coding.swift in Sources */ = {isa = PBXBuildFile; fileRef = 49EB68C31F7B3CB400D89D40 /* Coding.swift */; }; + 997DF2AE287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; }; + 997DF2AF287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; }; + 997DF2B0287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; }; + 997DF2B1287FC06D00F8DF95 /* Query+with.swift in Sources */ = {isa = PBXBuildFile; fileRef = 997DF2AD287FC06D00F8DF95 /* Query+with.swift */; }; D4DB368C20C09CFB00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; }; D4DB368D20C09CFC00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; }; D4DB368E20C09CFD00D5A58E /* SelectTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = D4DB368A20C09C9B00D5A58E /* SelectTests.swift */; }; @@ -260,6 +264,7 @@ 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; }; 3DDC112E26CDBA0200CE369F /* SQLiteObjc.h */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.c.h; name = SQLiteObjc.h; path = ../SQLiteObjc/include/SQLiteObjc.h; sourceTree = ""; }; 49EB68C31F7B3CB400D89D40 /* Coding.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = Coding.swift; sourceTree = ""; }; + 997DF2AD287FC06D00F8DF95 /* Query+with.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = "Query+with.swift"; sourceTree = ""; }; A121AC451CA35C79005A31D1 /* SQLite.framework */ = {isa = PBXFileReference; explicitFileType = wrapper.framework; includeInIndex = 0; path = SQLite.framework; sourceTree = BUILT_PRODUCTS_DIR; }; D4DB368A20C09C9B00D5A58E /* SelectTests.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = SelectTests.swift; sourceTree = ""; }; EE247AD31C3F04ED00AE3E12 /* SQLite.framework */ = {isa = PBXFileReference; explicitFileType = wrapper.framework; includeInIndex = 0; path = SQLite.framework; sourceTree = BUILT_PRODUCTS_DIR; }; @@ -499,6 +504,7 @@ EE247AFE1C3F06E900AE3E12 /* Expression.swift */, EE247AFF1C3F06E900AE3E12 /* Operators.swift */, EE247B001C3F06E900AE3E12 /* Query.swift */, + 997DF2AD287FC06D00F8DF95 /* Query+with.swift */, EE247B011C3F06E900AE3E12 /* Schema.swift */, EE247B021C3F06E900AE3E12 /* Setter.swift */, 49EB68C31F7B3CB400D89D40 /* Coding.swift */, @@ -862,6 +868,7 @@ 19A17FF4A10B44D3937C8CAC /* Errors.swift in Sources */, 19A1737286A74F3CF7412906 /* DateAndTimeFunctions.swift in Sources */, 19A17073552293CA063BEA66 /* Result.swift in Sources */, + 997DF2B0287FC06D00F8DF95 /* Query+with.swift in Sources */, 19A179B59450FE7C4811AB8A /* Connection+Aggregation.swift in Sources */, ); runOnlyForDeploymentPostprocessing = 0; @@ -904,6 +911,7 @@ files = ( 3D67B3F91DB246E700A4F4C6 /* SQLiteObjc.m in Sources */, 49EB68C71F7B3CB400D89D40 /* Coding.swift in Sources */, + 997DF2B1287FC06D00F8DF95 /* Query+with.swift in Sources */, 3D67B3F71DB246D700A4F4C6 /* Foundation.swift in Sources */, 3D67B3F81DB246D700A4F4C6 /* Helpers.swift in Sources */, 3D67B3E91DB246D100A4F4C6 /* Statement.swift in Sources */, @@ -959,6 +967,7 @@ 19A1792C0520D4E83C2EB075 /* Errors.swift in Sources */, 19A17E29278A12BC4F542506 /* DateAndTimeFunctions.swift in Sources */, 19A173EFEF0B3BD0B3ED406C /* Result.swift in Sources */, + 997DF2AE287FC06D00F8DF95 /* Query+with.swift in Sources */, 19A176376CB6A94759F7980A /* Connection+Aggregation.swift in Sources */, ); runOnlyForDeploymentPostprocessing = 0; @@ -1024,6 +1033,7 @@ 19A17490543609FCED53CACC /* Errors.swift in Sources */, 19A17152E32A9585831E3FE0 /* DateAndTimeFunctions.swift in Sources */, 19A17F1B3F0A3C96B5ED6D64 /* Result.swift in Sources */, + 997DF2AF287FC06D00F8DF95 /* Query+with.swift in Sources */, 19A170ACC97B19730FB7BA4D /* Connection+Aggregation.swift in Sources */, ); runOnlyForDeploymentPostprocessing = 0; diff --git a/Sources/SQLite/Typed/Query+with.swift b/Sources/SQLite/Typed/Query+with.swift new file mode 100644 index 00000000..d06c8896 --- /dev/null +++ b/Sources/SQLite/Typed/Query+with.swift @@ -0,0 +1,117 @@ +// +// SQLite.swift +// https://github.com/stephencelis/SQLite.swift +// Copyright © 2014-2015 Stephen Celis. +// +// Permission is hereby granted, free of charge, to any person obtaining a copy +// of this software and associated documentation files (the "Software"), to deal +// in the Software without restriction, including without limitation the rights +// to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +// copies of the Software, and to permit persons to whom the Software is +// furnished to do so, subject to the following conditions: +// +// The above copyright notice and this permission notice shall be included in +// all copies or substantial portions of the Software. +// +// THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +// IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +// FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +// AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +// LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +// OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN +// THE SOFTWARE. +// +import Foundation + +extension QueryType { + + /// Sets a `WITH` clause on the query. + /// + /// let users = Table("users") + /// let id = Expression("email") + /// let name = Expression("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. + /// + /// - hint: 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, + hint: MaterializationHint? = nil, as subquery: QueryType) -> Self { + var query = self + let clause = WithClauses.Clause(alias: alias, columns: columns, hint: hint, query: subquery) + query.clauses.with.recursive = query.clauses.with.recursive || recursive + query.clauses.with.clauses.append(clause) + return query + } + + /// self.clauses.with transformed to an Expressible + var withClause: Expressible? { + guard !clauses.with.clauses.isEmpty else { + return nil + } + + let innerClauses = ", ".join(clauses.with.clauses.map { (clause) in + let hintExpr: Expression? + if let hint = clause.hint { + hintExpr = Expression(literal: hint.rawValue) + } else { + hintExpr = nil + } + + let columnExpr: Expression? + if let columns = clause.columns { + columnExpr = "".wrap(", ".join(columns)) + } else { + columnExpr = nil + } + + let expressions: [Expressible?] = [ + clause.alias.tableName(), + columnExpr, + Expression(literal: "AS"), + hintExpr, + "".wrap(clause.query) as Expression + ] + + return " ".join(expressions.compactMap { $0 }) + }) + + return " ".join([ + Expression(literal: clauses.with.recursive ? "WITH RECURSIVE" : "WITH"), + innerClauses + ]) + } +} + +/// Materialization hints for `WITH` clause +public enum MaterializationHint: String { + + case materialized = "MATERIALIZED" + + case notMaterialized = "NOT MATERIALIZED" +} + +struct WithClauses { + struct Clause { + var alias: Table + var columns: [Expressible]? + var hint: 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] = [] +} diff --git a/Sources/SQLite/Typed/Query.swift b/Sources/SQLite/Typed/Query.swift index 93dc2a73..cfa7544e 100644 --- a/Sources/SQLite/Typed/Query.swift +++ b/Sources/SQLite/Typed/Query.swift @@ -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 } @@ -596,9 +598,9 @@ extension QueryType { return nil } - return " ".join(clauses.union.map { query in + return " ".join(clauses.union.map { (all, query) in " ".join([ - Expression(literal: "UNION"), + Expression(literal: all ? "UNION ALL" : "UNION"), query ]) }) @@ -856,6 +858,7 @@ extension QueryType { public var expression: Expression { let clauses: [Expressible?] = [ + withClause, selectClause, joinClause, whereClause, @@ -1251,7 +1254,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) diff --git a/Tests/SQLiteTests/QueryIntegrationTests.swift b/Tests/SQLiteTests/QueryIntegrationTests.swift index f3b4bcd3..db4e2e4e 100644 --- a/Tests/SQLiteTests/QueryIntegrationTests.swift +++ b/Tests/SQLiteTests/QueryIntegrationTests.swift @@ -230,6 +230,47 @@ class QueryIntegrationTests: SQLiteTestCase { let result = Array(try db.prepare(users.select(email).order(Expression.random()).limit(1))) XCTAssertEqual(1, result.count) } + + func test_with_recursive() { + let nodes = Table("nodes") + let id = Expression("id") + let parent = Expression("parent") + let value = Expression("value") + + try! db.run(nodes.create { builder in + builder.column(id) + builder.column(parent) + builder.column(value) + }) + + try! db.run(nodes.insertMany([ + [id <- 0, parent <- nil, value <- 2], + [id <- 1, parent <- 0, value <- 4], + [id <- 2, parent <- 0, value <- 9], + [id <- 3, parent <- 2, value <- 8], + [id <- 4, parent <- 2, value <- 7], + [id <- 5, parent <- 4, value <- 3] + ])) + + // Compute the sum of the values of node 5 and its ancestors + let ancestors = Table("ancestors") + let sum = try! db.scalar( + ancestors + .select(value.sum) + .with(ancestors, + columns: [id, parent, value], + recursive: true, + as: nodes + .where(id == 5) + .union(all: true, + nodes.join(ancestors, on: nodes[id] == ancestors[parent]) + .select(nodes[id], nodes[parent], nodes[value]) + ) + ) + ) + + XCTAssertEqual(21, sum) + } } extension Connection { diff --git a/Tests/SQLiteTests/QueryTests.swift b/Tests/SQLiteTests/QueryTests.swift index b2f679e0..eae1d923 100644 --- a/Tests/SQLiteTests/QueryTests.swift +++ b/Tests/SQLiteTests/QueryTests.swift @@ -59,6 +59,14 @@ class QueryTests: XCTestCase { assertSQL("SELECT DISTINCT * FROM \"users\"", users.select(distinct: *)) } + func test_union_compilesUnionClause() { + assertSQL("SELECT * FROM \"users\" UNION SELECT * FROM \"posts\"", users.union(posts)) + } + + func test_union_compilesUnionAllClause() { + assertSQL("SELECT * FROM \"users\" UNION ALL SELECT * FROM \"posts\"", users.union(all: true, posts)) + } + func test_join_compilesJoinClause() { assertSQL( "SELECT * FROM \"users\" INNER JOIN \"posts\" ON (\"posts\".\"user_id\" = \"users\".\"id\")", @@ -220,6 +228,62 @@ class QueryTests: XCTestCase { ) } + 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_compilesWithRecursiveClause() { + let temp = Table("temp") + + assertSQL("WITH RECURSIVE \"temp\" AS (SELECT * FROM \"users\") SELECT * FROM \"temp\"", + temp.with(temp, recursive: true, as: users)) + } + + func test_with_compilesWithMaterializedClause() { + let temp = Table("temp") + + assertSQL("WITH \"temp\" AS MATERIALIZED (SELECT * FROM \"users\") SELECT * FROM \"temp\"", + temp.with(temp, hint: .materialized, as: users)) + } + + func test_with_compilesWithNotMaterializedClause() { + let temp = Table("temp") + + assertSQL("WITH \"temp\" AS NOT MATERIALIZED (SELECT * FROM \"users\") SELECT * FROM \"temp\"", + temp.with(temp, hint: .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, hint: 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, hint: .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( "INSERT INTO \"users\" (\"email\", \"age\") VALUES ('alice@example.com', 30)",