Skip to content

Commit 4ea6f4e

Browse files
author
Nathan Fallet
authored
Merge pull request stephencelis#882 from andyfinnell/features/upsert-upstream
2 parents 511160b + 0fa531d commit 4ea6f4e

File tree

5 files changed

+129
-1
lines changed

5 files changed

+129
-1
lines changed

Documentation/Index.md

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -35,6 +35,7 @@
3535
- [Sorting Rows](#sorting-rows)
3636
- [Limiting and Paging Results](#limiting-and-paging-results)
3737
- [Aggregation](#aggregation)
38+
- [Upserting Rows](#upserting-rows)
3839
- [Updating Rows](#updating-rows)
3940
- [Deleting Rows](#deleting-rows)
4041
- [Transactions and Savepoints](#transactions-and-savepoints)
@@ -1100,6 +1101,33 @@ let count = try db.scalar(users.filter(name != nil).count)
11001101
> // SELECT count(DISTINCT "name") FROM "users"
11011102
> ```
11021103

1104+
## Upserting Rows
1105+
1106+
We can upsert rows into a table by calling a [query’s](#queries) `upsert`
1107+
function with a list of [setters](#setters)—typically [typed column
1108+
expressions](#expressions) and values (which can also be expressions)—each
1109+
joined by the `<-` operator. Upserting is like inserting, except if there is a
1110+
conflict on the specified column value, SQLite will perform an update on the row instead.
1111+
1112+
```swift
1113+
try db.run(users.upsert(email <- "[email protected]", name <- "Alice"), onConflictOf: email)
1114+
// INSERT INTO "users" ("email", "name") VALUES ('[email protected]', 'Alice') ON CONFLICT (\"email\") DO UPDATE SET \"name\" = \"excluded\".\"name\"
1115+
```
1116+
1117+
The `upsert` function, when run successfully, returns an `Int64` representing
1118+
the inserted row’s [`ROWID`][ROWID].
1119+
1120+
```swift
1121+
do {
1122+
let rowid = try db.run(users.upsert(email <- "[email protected]", name <- "Alice", onConflictOf: email))
1123+
print("inserted id: \(rowid)")
1124+
} catch {
1125+
print("insertion failed: \(error)")
1126+
}
1127+
```
1128+
1129+
The [`insert`](#inserting-rows), [`update`](#updating-rows), and [`delete`](#deleting-rows) functions
1130+
follow similar patterns.
11031131

11041132
## Updating Rows
11051133

Sources/SQLite/Typed/Coding.swift

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -45,6 +45,29 @@ extension QueryType {
4545
return self.insert(encoder.setters + otherSetters)
4646
}
4747

48+
49+
/// Creates an `INSERT ON CONFLICT DO UPDATE` statement, aka upsert, by encoding the given object
50+
/// This method converts any custom nested types to JSON data and does not handle any sort
51+
/// of object relationships. If you want to support relationships between objects you will
52+
/// have to provide your own Encodable implementations that encode the correct ids.
53+
///
54+
/// - Parameters:
55+
///
56+
/// - encodable: An encodable object to insert
57+
///
58+
/// - userInfo: User info to be passed to encoder
59+
///
60+
/// - otherSetters: Any other setters to include in the insert
61+
///
62+
/// - onConflictOf: The column that if conflicts should trigger an update instead of insert.
63+
///
64+
/// - Returns: An `INSERT` statement fort the encodable object
65+
public func upsert(_ encodable: Encodable, userInfo: [CodingUserInfoKey:Any] = [:], otherSetters: [Setter] = [], onConflictOf conflicting: Expressible) throws -> Insert {
66+
let encoder = SQLiteEncoder(userInfo: userInfo)
67+
try encodable.encode(to: encoder)
68+
return self.upsert(encoder.setters + otherSetters, onConflictOf: conflicting)
69+
}
70+
4871
/// Creates an `UPDATE` statement by encoding the given object
4972
/// This method converts any custom nested types to JSON data and does not handle any sort
5073
/// of object relationships. If you want to support relationships between objects you will

Sources/SQLite/Typed/Query.swift

Lines changed: 39 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -672,6 +672,45 @@ extension QueryType {
672672
query.expression
673673
]).expression)
674674
}
675+
676+
// MARK: UPSERT
677+
678+
public func upsert(_ insertValues: Setter..., onConflictOf conflicting: Expressible) -> Insert {
679+
return upsert(insertValues, onConflictOf: conflicting)
680+
}
681+
682+
public func upsert(_ insertValues: [Setter], onConflictOf conflicting: Expressible) -> Insert {
683+
let setValues = insertValues.filter { $0.column.asSQL() != conflicting.asSQL() }
684+
.map { Setter(excluded: $0.column) }
685+
return upsert(insertValues, onConflictOf: conflicting, set: setValues)
686+
}
687+
688+
public func upsert(_ insertValues: Setter..., onConflictOf conflicting: Expressible, set setValues: [Setter]) -> Insert {
689+
return upsert(insertValues, onConflictOf: conflicting, set: setValues)
690+
}
691+
692+
public func upsert(_ insertValues: [Setter], onConflictOf conflicting: Expressible, set setValues: [Setter]) -> Insert {
693+
let insert = insertValues.reduce((columns: [Expressible](), values: [Expressible]())) { insert, setter in
694+
(insert.columns + [setter.column], insert.values + [setter.value])
695+
}
696+
697+
let clauses: [Expressible?] = [
698+
Expression<Void>(literal: "INSERT"),
699+
Expression<Void>(literal: "INTO"),
700+
tableName(),
701+
"".wrap(insert.columns) as Expression<Void>,
702+
Expression<Void>(literal: "VALUES"),
703+
"".wrap(insert.values) as Expression<Void>,
704+
whereClause,
705+
Expression<Void>(literal: "ON CONFLICT"),
706+
"".wrap(conflicting) as Expression<Void>,
707+
Expression<Void>(literal: "DO UPDATE SET"),
708+
", ".join(setValues.map { $0.expression })
709+
]
710+
711+
return Insert(" ".join(clauses.compactMap { $0 }).expression)
712+
}
713+
675714

676715
// MARK: UPDATE
677716

Sources/SQLite/Typed/Setter.swift

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -60,6 +60,11 @@ public struct Setter {
6060
self.value = Expression<V?>(value: value)
6161
}
6262

63+
init(excluded column: Expressible) {
64+
let excluded = Expression<Void>("excluded")
65+
self.column = column
66+
self.value = ".".join([excluded, column.expression])
67+
}
6368
}
6469

6570
extension Setter : Expressible {

Tests/SQLiteTests/QueryTests.swift

Lines changed: 34 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -270,6 +270,24 @@ class QueryTests : XCTestCase {
270270
)
271271
}
272272

273+
func test_upsert_withOnConflict_compilesInsertOrOnConflictExpression() {
274+
AssertSQL(
275+
"INSERT INTO \"users\" (\"email\", \"age\") VALUES ('[email protected]', 30) ON CONFLICT (\"email\") DO UPDATE SET \"age\" = \"excluded\".\"age\"",
276+
users.upsert(email <- "[email protected]", age <- 30, onConflictOf: email)
277+
)
278+
}
279+
280+
func test_upsert_encodable() throws {
281+
let emails = Table("emails")
282+
let string = Expression<String>("string")
283+
let value = TestCodable(int: 1, string: "2", bool: true, float: 3, double: 4, optional: nil, sub: nil)
284+
let insert = try emails.upsert(value, onConflictOf: string)
285+
AssertSQL(
286+
"INSERT INTO \"emails\" (\"int\", \"string\", \"bool\", \"float\", \"double\") VALUES (1, '2', 1, 3.0, 4.0) ON CONFLICT (\"string\") DO UPDATE SET \"int\" = \"excluded\".\"int\", \"bool\" = \"excluded\".\"bool\", \"float\" = \"excluded\".\"float\", \"double\" = \"excluded\".\"double\"",
287+
insert
288+
)
289+
}
290+
273291
func test_update_compilesUpdateExpression() {
274292
AssertSQL(
275293
"UPDATE \"users\" SET \"age\" = 30, \"admin\" = 1 WHERE (\"id\" = 1)",
@@ -378,7 +396,8 @@ class QueryIntegrationTests : SQLiteTestCase {
378396

379397
let id = Expression<Int64>("id")
380398
let email = Expression<String>("email")
381-
399+
let age = Expression<Int>("age")
400+
382401
override func setUp() {
383402
super.setUp()
384403

@@ -486,6 +505,20 @@ class QueryIntegrationTests : SQLiteTestCase {
486505
XCTAssertEqual(1, id)
487506
}
488507

508+
func test_upsert() throws {
509+
let fetchAge = { () throws -> Int? in
510+
return try self.db.pluck(self.users.filter(self.email == "[email protected]")).flatMap { $0[self.age] }
511+
}
512+
513+
let id = try db.run(users.upsert(email <- "[email protected]", age <- 30, onConflictOf: email))
514+
XCTAssertEqual(1, id)
515+
XCTAssertEqual(30, try fetchAge())
516+
517+
let nextId = try db.run(users.upsert(email <- "[email protected]", age <- 42, onConflictOf: email))
518+
XCTAssertEqual(1, nextId)
519+
XCTAssertEqual(42, try fetchAge())
520+
}
521+
489522
func test_update() {
490523
let changes = try! db.run(users.update(email <- "[email protected]"))
491524
XCTAssertEqual(0, changes)

0 commit comments

Comments
 (0)