Skip to content

Commit

Permalink
Merge pull request #1228 from geoffmacd/window-functions
Browse files Browse the repository at this point in the history
Implements built-in window functions
  • Loading branch information
nathanfallet committed Feb 23, 2024
2 parents 8b96864 + 2fc62a9 commit f4ce124
Show file tree
Hide file tree
Showing 6 changed files with 325 additions and 3 deletions.
6 changes: 6 additions & 0 deletions Documentation/Index.md
Expand Up @@ -64,6 +64,7 @@
- [Other Operators](#other-operators)
- [Core SQLite Functions](#core-sqlite-functions)
- [Aggregate SQLite Functions](#aggregate-sqlite-functions)
- [Window SQLite Functions](#window-sqlite-functions)
- [Date and Time Functions](#date-and-time-functions)
- [Custom SQL Functions](#custom-sql-functions)
- [Custom Collations](#custom-collations)
Expand Down Expand Up @@ -1871,6 +1872,11 @@ Most of SQLite’s
[aggregate functions](https://www.sqlite.org/lang_aggfunc.html) have been
surfaced in and type-audited for SQLite.swift.

## Window SQLite Functions

Most of SQLite's [window functions](https://www.sqlite.org/windowfunctions.html) have been
surfaced in and type-audited for SQLite.swift. Currently only `OVER (ORDER BY ...)` windowing is possible.

## Date and Time functions

SQLite's [date and time](https://www.sqlite.org/lang_datefunc.html)
Expand Down
18 changes: 18 additions & 0 deletions SQLite.xcodeproj/project.pbxproj
Expand Up @@ -195,6 +195,13 @@
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 */; };
64A8EE432B095FBB00F583F7 /* WindowFunctions.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */; };
64A8EE442B095FBB00F583F7 /* WindowFunctions.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */; };
64A8EE452B095FBB00F583F7 /* WindowFunctions.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */; };
64A8EE462B095FBB00F583F7 /* WindowFunctions.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */; };
64B8E1702B09748000545AFB /* WindowFunctionsTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64B8E16F2B09748000545AFB /* WindowFunctionsTests.swift */; };
64B8E1712B09748000545AFB /* WindowFunctionsTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64B8E16F2B09748000545AFB /* WindowFunctionsTests.swift */; };
64B8E1722B09748000545AFB /* WindowFunctionsTests.swift in Sources */ = {isa = PBXBuildFile; fileRef = 64B8E16F2B09748000545AFB /* WindowFunctionsTests.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 */; };
Expand Down Expand Up @@ -335,6 +342,8 @@
3DF7B79B2884C901005DD8CA /* Planning.md */ = {isa = PBXFileReference; lastKnownFileType = net.daringfireball.markdown; path = Planning.md; sourceTree = "<group>"; };
3DFC0B862886C239001C8FC9 /* Package.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = Package.swift; sourceTree = "<group>"; };
49EB68C31F7B3CB400D89D40 /* Coding.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = Coding.swift; sourceTree = "<group>"; };
64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = WindowFunctions.swift; sourceTree = "<group>"; };
64B8E16F2B09748000545AFB /* WindowFunctionsTests.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = WindowFunctionsTests.swift; sourceTree = "<group>"; };
997DF2AD287FC06D00F8DF95 /* Query+with.swift */ = {isa = PBXFileReference; lastKnownFileType = sourcecode.swift; path = "Query+with.swift"; sourceTree = "<group>"; };
A121AC451CA35C79005A31D1 /* SQLite.framework */ = {isa = PBXFileReference; explicitFileType = wrapper.framework; includeInIndex = 0; path = SQLite.framework; sourceTree = BUILT_PRODUCTS_DIR; };
DB58B21028FB864300F8EEA4 /* SchemaReader.swift */ = {isa = PBXFileReference; fileEncoding = 4; lastKnownFileType = sourcecode.swift; path = SchemaReader.swift; sourceTree = "<group>"; };
Expand Down Expand Up @@ -476,6 +485,7 @@
19A177EF5E2D91BA86DA4480 /* CustomAggregationTests.swift */,
19A1709D5BDD2691BA160012 /* SetterTests.swift */,
19A174FE5B47A97937A27276 /* RowTests.swift */,
64B8E16F2B09748000545AFB /* WindowFunctionsTests.swift */,
);
path = Typed;
sourceTree = "<group>";
Expand Down Expand Up @@ -607,6 +617,7 @@
isa = PBXGroup;
children = (
EE247AFA1C3F06E900AE3E12 /* AggregateFunctions.swift */,
64A8EE422B095FBB00F583F7 /* WindowFunctions.swift */,
EE247AFB1C3F06E900AE3E12 /* Collation.swift */,
EE247AFC1C3F06E900AE3E12 /* CoreFunctions.swift */,
EE247AFD1C3F06E900AE3E12 /* CustomFunctions.swift */,
Expand Down Expand Up @@ -960,6 +971,7 @@
3DF7B78A28842972005DD8CA /* Connection+Attach.swift in Sources */,
03A65E811C6BB2FB0062603F /* CustomFunctions.swift in Sources */,
03A65E7A1C6BB2F70062603F /* Statement.swift in Sources */,
64A8EE452B095FBB00F583F7 /* WindowFunctions.swift in Sources */,
03A65E741C6BB2DA0062603F /* Helpers.swift in Sources */,
03A65E831C6BB2FB0062603F /* Operators.swift in Sources */,
03A65E851C6BB2FB0062603F /* Schema.swift in Sources */,
Expand Down Expand Up @@ -1014,6 +1026,7 @@
19A17746150A815944A6820B /* SelectTests.swift in Sources */,
19A1766135CE9786B1878603 /* ValueTests.swift in Sources */,
19A177D5C6542E2D572162E5 /* QueryIntegrationTests.swift in Sources */,
64B8E1722B09748000545AFB /* WindowFunctionsTests.swift in Sources */,
19A178DF5A96CFEFF1E271F6 /* AggregateFunctionsTests.swift in Sources */,
19A17437659BD7FD787D94A6 /* CustomAggregationTests.swift in Sources */,
19A17F907258E524B3CA2FAE /* SetterTests.swift in Sources */,
Expand Down Expand Up @@ -1057,6 +1070,7 @@
19A17DC282E36C4F41AA440B /* Errors.swift in Sources */,
19A173668D948AD4DF1F5352 /* DateAndTimeFunctions.swift in Sources */,
19A17DF8D4F13A20F5D2269E /* Result.swift in Sources */,
64A8EE462B095FBB00F583F7 /* WindowFunctions.swift in Sources */,
19A17DFE05ED8B1F7C45F7EE /* SchemaChanger.swift in Sources */,
19A17D1BEABA610ABF003D67 /* SchemaDefinitions.swift in Sources */,
19A17A33EA026C2E2CEBAF36 /* Connection+Schema.swift in Sources */,
Expand All @@ -1081,6 +1095,7 @@
EE247B151C3F06E900AE3E12 /* Setter.swift in Sources */,
3DF7B78828842972005DD8CA /* Connection+Attach.swift in Sources */,
EE247B101C3F06E900AE3E12 /* CustomFunctions.swift in Sources */,
64A8EE432B095FBB00F583F7 /* WindowFunctions.swift in Sources */,
EE247B091C3F06E900AE3E12 /* FTS4.swift in Sources */,
EE247B081C3F06E900AE3E12 /* Value.swift in Sources */,
EE247B121C3F06E900AE3E12 /* Operators.swift in Sources */,
Expand Down Expand Up @@ -1135,6 +1150,7 @@
19A17F7977364EC8CD33C3C3 /* SelectTests.swift in Sources */,
19A17FD22EF43DF428DD93BA /* ValueTests.swift in Sources */,
19A177AA5922527BBDC77CF9 /* QueryIntegrationTests.swift in Sources */,
64B8E1702B09748000545AFB /* WindowFunctionsTests.swift in Sources */,
19A179786A6826D58A70F8BC /* AggregateFunctionsTests.swift in Sources */,
19A1793972BDDDB027C113BB /* CustomAggregationTests.swift in Sources */,
19A1773155AC2BF2CA86A473 /* SetterTests.swift in Sources */,
Expand All @@ -1161,6 +1177,7 @@
3DF7B78928842972005DD8CA /* Connection+Attach.swift in Sources */,
EE247B701C3F3FEC00AE3E12 /* CustomFunctions.swift in Sources */,
EE247B691C3F3FEC00AE3E12 /* Statement.swift in Sources */,
64A8EE442B095FBB00F583F7 /* WindowFunctions.swift in Sources */,
EE247B641C3F3FDB00AE3E12 /* Helpers.swift in Sources */,
EE247B721C3F3FEC00AE3E12 /* Operators.swift in Sources */,
EE247B741C3F3FEC00AE3E12 /* Schema.swift in Sources */,
Expand Down Expand Up @@ -1215,6 +1232,7 @@
19A17DE1FCDB5695702AD24D /* SelectTests.swift in Sources */,
19A1726002D24C14F876C8FE /* ValueTests.swift in Sources */,
19A173389E53CB24DFA8CEDD /* QueryIntegrationTests.swift in Sources */,
64B8E1712B09748000545AFB /* WindowFunctionsTests.swift in Sources */,
19A170C56745F9D722A73D77 /* AggregateFunctionsTests.swift in Sources */,
19A1772EBE65173EDFB1AFCA /* CustomAggregationTests.swift in Sources */,
19A17E0ABA6C415F014CD51C /* SetterTests.swift in Sources */,
Expand Down
6 changes: 3 additions & 3 deletions Sources/SQLite/Typed/AggregateFunctions.swift
Expand Up @@ -166,7 +166,7 @@ extension ExpressionType where UnderlyingType: Value, UnderlyingType.Datatype: N
/// salary.average
/// // avg("salary")
///
/// - Returns: A copy of the expression wrapped with the `min` aggregate
/// - Returns: A copy of the expression wrapped with the `avg` aggregate
/// function.
public var average: Expression<Double?> {
Function.avg.wrap(self)
Expand All @@ -179,7 +179,7 @@ extension ExpressionType where UnderlyingType: Value, UnderlyingType.Datatype: N
/// salary.sum
/// // sum("salary")
///
/// - Returns: A copy of the expression wrapped with the `min` aggregate
/// - Returns: A copy of the expression wrapped with the `sum` aggregate
/// function.
public var sum: Expression<UnderlyingType?> {
Function.sum.wrap(self)
Expand All @@ -192,7 +192,7 @@ extension ExpressionType where UnderlyingType: Value, UnderlyingType.Datatype: N
/// salary.total
/// // total("salary")
///
/// - Returns: A copy of the expression wrapped with the `min` aggregate
/// - Returns: A copy of the expression wrapped with the `total` aggregate
/// function.
public var total: Expression<Double> {
Function.total.wrap(self)
Expand Down
145 changes: 145 additions & 0 deletions Sources/SQLite/Typed/WindowFunctions.swift
@@ -0,0 +1,145 @@
import Foundation

// see https://www.sqlite.org/windowfunctions.html#builtins
private enum WindowFunction: String {
// swiftlint:disable identifier_name
case ntile
case row_number
case rank
case dense_rank
case percent_rank
case cume_dist
case lag
case lead
case first_value
case last_value
case nth_value
// swiftlint:enable identifier_name

func wrap<T>(_ value: Int? = nil) -> Expression<T> {
if let value {
return self.rawValue.wrap(Expression(value: value))
}
return Expression(literal: "\(rawValue)()")
}

func over<T>(value: Int? = nil, _ orderBy: Expressible) -> Expression<T> {
return Expression<T>(" ".join([
self.wrap(value),
Expression<T>("OVER (ORDER BY \(orderBy.expression.template))", orderBy.expression.bindings)
]).expression)
}

func over<T>(valueExpr: Expressible, _ orderBy: Expressible) -> Expression<T> {
return Expression<T>(" ".join([
self.rawValue.wrap(valueExpr),
Expression<T>("OVER (ORDER BY \(orderBy.expression.template))", orderBy.expression.bindings)
]).expression)
}
}

extension ExpressionType where UnderlyingType: Value {
/// Builds a copy of the expression with `lag(self, offset, default) OVER (ORDER BY {orderBy})` window function
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `lag(self, offset, default) OVER (ORDER BY {orderBy})` window function
public func lag(offset: Int = 0, default: Expressible? = nil, _ orderBy: Expressible) -> Expression<UnderlyingType> {
if let defaultExpression = `default` {
return Expression(
"lag(\(template), \(offset), \(defaultExpression.asSQL())) OVER (ORDER BY \(orderBy.expression.template))",
bindings + orderBy.expression.bindings
)

}
return Expression("lag(\(template), \(offset)) OVER (ORDER BY \(orderBy.expression.template))", bindings + orderBy.expression.bindings)
}

/// Builds a copy of the expression with `lead(self, offset, default) OVER (ORDER BY {orderBy})` window function
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `lead(self, offset, default) OVER (ORDER BY {orderBy})` window function
public func lead(offset: Int = 0, default: Expressible? = nil, _ orderBy: Expressible) -> Expression<UnderlyingType> {
if let defaultExpression = `default` {
return Expression(
"lead(\(template), \(offset), \(defaultExpression.asSQL())) OVER (ORDER BY \(orderBy.expression.template))",
bindings + orderBy.expression.bindings)

}
return Expression("lead(\(template), \(offset)) OVER (ORDER BY \(orderBy.expression.template))", bindings + orderBy.expression.bindings)
}

/// Builds a copy of the expression with `first_value(self) OVER (ORDER BY {orderBy})` window function
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `first_value(self) OVER (ORDER BY {orderBy})` window function
public func firstValue(_ orderBy: Expressible) -> Expression<UnderlyingType> {
WindowFunction.first_value.over(valueExpr: self, orderBy)
}

/// Builds a copy of the expression with `last_value(self) OVER (ORDER BY {orderBy})` window function
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `last_value(self) OVER (ORDER BY {orderBy})` window function
public func lastValue(_ orderBy: Expressible) -> Expression<UnderlyingType> {
WindowFunction.last_value.over(valueExpr: self, orderBy)
}

/// Builds a copy of the expression with `nth_value(self) OVER (ORDER BY {orderBy})` window function
///
/// - Parameter index: Row N of the window frame to return
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `nth_value(self) OVER (ORDER BY {orderBy})` window function
public func value(_ index: Int, _ orderBy: Expressible) -> Expression<UnderlyingType> {
Expression("nth_value(\(template), \(index)) OVER (ORDER BY \(orderBy.expression.template))", bindings + orderBy.expression.bindings)
}
}

/// Builds an expression representing `ntile(size) OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `ntile(size) OVER (ORDER BY {orderBy})`
public func ntile(_ size: Int, _ orderBy: Expressible) -> Expression<Int> {
// Expression.ntile(size, orderBy)

WindowFunction.ntile.over(value: size, orderBy)
}

/// Builds an expression representing `row_count() OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `row_count() OVER (ORDER BY {orderBy})`
public func rowNumber(_ orderBy: Expressible) -> Expression<Int> {
WindowFunction.row_number.over(orderBy)
}

/// Builds an expression representing `rank() OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `rank() OVER (ORDER BY {orderBy})`
public func rank(_ orderBy: Expressible) -> Expression<Int> {
WindowFunction.rank.over(orderBy)
}

/// Builds an expression representing `dense_rank() OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `dense_rank() OVER ('over')`
public func denseRank(_ orderBy: Expressible) -> Expression<Int> {
WindowFunction.dense_rank.over(orderBy)
}

/// Builds an expression representing `percent_rank() OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `percent_rank() OVER (ORDER BY {orderBy})`
public func percentRank(_ orderBy: Expressible) -> Expression<Double> {
WindowFunction.percent_rank.over(orderBy)
}

/// Builds an expression representing `cume_dist() OVER (ORDER BY {orderBy})`
///
/// - Parameter orderBy: Expression to evaluate window order
/// - Returns: An expression returning `cume_dist() OVER (ORDER BY {orderBy})`
public func cumeDist(_ orderBy: Expressible) -> Expression<Double> {
WindowFunction.cume_dist.over(orderBy)
}
95 changes: 95 additions & 0 deletions Tests/SQLiteTests/Typed/QueryIntegrationTests.swift
Expand Up @@ -322,6 +322,101 @@ class QueryIntegrationTests: SQLiteTestCase {
XCTAssertNotNil(row[name])
XCTAssertNotNil(row[email])
}

func test_select_ntile_function() throws {
let users = Table("users")

try insertUser("Joey")
try insertUser("Timmy")
try insertUser("Jimmy")
try insertUser("Billy")

let bucket = ntile(1, id.asc)
try db.prepare(users.select(id, bucket)).forEach {
XCTAssertEqual($0[bucket], 1) // only 1 window
}
}

func test_select_cume_dist_function() throws {
let users = Table("users")

try insertUser("Joey")
try insertUser("Timmy")
try insertUser("Jimmy")
try insertUser("Billy")

let cumeDist = cumeDist(email)
let results = try db.prepare(users.select(id, cumeDist)).map {
$0[cumeDist]
}
XCTAssertEqual([0.25, 0.5, 0.75, 1], results)
}

func test_select_window_row_number() throws {
let users = Table("users")

try insertUser("Billy")
try insertUser("Jimmy")
try insertUser("Joey")
try insertUser("Timmy")

let rowNumber = rowNumber(email.asc)
var expectedRowNum = 1
try db.prepare(users.select(id, rowNumber)).forEach {
// should retrieve row numbers in order of INSERT above
XCTAssertEqual($0[rowNumber], expectedRowNum)
expectedRowNum += 1
}
}

func test_select_window_ranking() throws {
let users = Table("users")

try insertUser("Billy")
try insertUser("Jimmy")
try insertUser("Joey")
try insertUser("Timmy")

let percentRank = percentRank(email)
let actualPercentRank: [Int] = try db.prepare(users.select(id, percentRank)).map {
Int($0[percentRank] * 100)
}
XCTAssertEqual([0, 33, 66, 100], actualPercentRank)

let rank = rank(email)
let actualRank: [Int] = try db.prepare(users.select(id, rank)).map {
$0[rank]
}
XCTAssertEqual([1, 2, 3, 4], actualRank)

let denseRank = denseRank(email)
let actualDenseRank: [Int] = try db.prepare(users.select(id, denseRank)).map {
$0[denseRank]
}
XCTAssertEqual([1, 2, 3, 4], actualDenseRank)
}

func test_select_window_values() throws {
let users = Table("users")

try insertUser("Billy")
try insertUser("Jimmy")
try insertUser("Joey")
try insertUser("Timmy")

let firstValue = email.firstValue(email.desc)
try db.prepare(users.select(id, firstValue)).forEach {
XCTAssertEqual($0[firstValue], "Timmy@example.com") // should grab last email alphabetically
}

let lastValue = email.lastValue(email.asc)
var row = try db.pluck(users.select(id, lastValue))!
XCTAssertEqual(row[lastValue], "Billy@example.com")

let nthValue = email.value(1, email.asc)
row = try db.pluck(users.select(id, nthValue))!
XCTAssertEqual(row[nthValue], "Billy@example.com")
}
}

extension Connection {
Expand Down

0 comments on commit f4ce124

Please sign in to comment.