Skip to content

implements batch insert rows, insertMany() #1048

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

Merged
merged 12 commits into from
Aug 21, 2021
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 12 additions & 0 deletions Documentation/Index.md
Original file line number Diff line number Diff line change
Expand Up @@ -639,6 +639,18 @@ do {
}
```

Multiple rows can be inserted at once by similarily calling `insertMany` with an array of per-row [setters](#setters).

```swift
do {
let rowid = try db.run(users.insertMany([mail <- "[email protected]"], [email <- "[email protected]"]))
print("inserted id: \(rowid)")
} catch {
print("insertion failed: \(error)")
}
```


The [`update`](#updating-rows) and [`delete`](#deleting-rows) functions
follow similar patterns.

Expand Down
3 changes: 0 additions & 3 deletions Documentation/Planning.md
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,3 @@ be referred to when it comes time to add the corresponding feature._
_Features that are not actively being considered, perhaps because of no clean
type-safe way to implement them with the current Swift, or bugs, or just
general uncertainty._

* provide a mechanism for INSERT INTO multiple values, per
[#168](https://github.com/stephencelis/SQLite.swift/issues/168)
4 changes: 2 additions & 2 deletions Makefile
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
BUILD_TOOL = xcodebuild
BUILD_SCHEME = SQLite Mac
IOS_SIMULATOR = iPhone XS
IOS_VERSION = 12.4
IOS_SIMULATOR = iPhone 12
IOS_VERSION = 14.4
ifeq ($(BUILD_SCHEME),SQLite iOS)
BUILD_ARGUMENTS = -scheme "$(BUILD_SCHEME)" -destination "platform=iOS Simulator,name=$(IOS_SIMULATOR),OS=$(IOS_VERSION)"
else
Expand Down
24 changes: 23 additions & 1 deletion Sources/SQLite/Typed/Coding.swift
Original file line number Diff line number Diff line change
Expand Up @@ -38,13 +38,35 @@ extension QueryType {
///
/// - otherSetters: Any other setters to include in the insert
///
/// - Returns: An `INSERT` statement fort the encodable object
/// - Returns: An `INSERT` statement for the encodable object
public func insert(_ encodable: Encodable, userInfo: [CodingUserInfoKey:Any] = [:], otherSetters: [Setter] = []) throws -> Insert {
let encoder = SQLiteEncoder(userInfo: userInfo)
try encodable.encode(to: encoder)
return self.insert(encoder.setters + otherSetters)
}

/// Creates a batch `INSERT` statement by encoding the array of given objects
/// This method converts any custom nested types to JSON data and does not handle any sort
/// of object relationships. If you want to support relationships between objects you will
/// have to provide your own Encodable implementations that encode the correct ids.
///
/// - Parameters:
///
/// - encodables: Encodable objects to insert
///
/// - userInfo: User info to be passed to encoder
///
/// - otherSetters: Any other setters to include in the inserts, per row/object.
///
/// - Returns: An `INSERT` statement for the encodable objects
public func insertMany(_ encodables: [Encodable], userInfo: [CodingUserInfoKey:Any] = [:], otherSetters: [Setter] = []) throws -> Insert {
let combinedSetters = try encodables.map { encodable -> [Setter] in
let encoder = SQLiteEncoder(userInfo: userInfo)
try encodable.encode(to: encoder)
return encoder.setters + otherSetters
}
return self.insertMany(combinedSetters)
}

/// Creates an `INSERT ON CONFLICT DO UPDATE` statement, aka upsert, by encoding the given object
/// This method converts any custom nested types to JSON data and does not handle any sort
Expand Down
39 changes: 39 additions & 0 deletions Sources/SQLite/Typed/Query.swift
Original file line number Diff line number Diff line change
Expand Up @@ -631,6 +631,18 @@ extension QueryType {
return insert(onConflict, values)
}

public func insertMany( _ values: [[Setter]]) -> Insert {
return insertMany(nil, values)
}

public func insertMany(or onConflict: OnConflict, _ values: [[Setter]]) -> Insert {
return insertMany(onConflict, values)
}

public func insertMany(or onConflict: OnConflict, _ values: [Setter]...) -> Insert {
return insertMany(onConflict, values)
}

fileprivate func insert(_ or: OnConflict?, _ values: [Setter]) -> Insert {
let insert = values.reduce((columns: [Expressible](), values: [Expressible]())) { insert, setter in
(insert.columns + [setter.column], insert.values + [setter.value])
Expand All @@ -650,6 +662,31 @@ extension QueryType {
return Insert(" ".join(clauses.compactMap { $0 }).expression)
}

fileprivate func insertMany(_ or: OnConflict?, _ values: [[Setter]]) -> Insert {
guard let firstInsert = values.first else {
// must be at least 1 object or else we don't know columns. Default to default inserts.
return insert()
}
let columns = firstInsert.map { $0.column }
let insertValues = values.map { rowValues in
rowValues.reduce([Expressible]()) { insert, setter in
insert + [setter.value]
}
}

let clauses: [Expressible?] = [
Expression<Void>(literal: "INSERT"),
or.map { Expression<Void>(literal: "OR \($0.rawValue)") },
Expression<Void>(literal: "INTO"),
tableName(),
"".wrap(columns) as Expression<Void>,
Expression<Void>(literal: "VALUES"),
", ".join(insertValues.map({ "".wrap($0) as Expression<Void> })),
whereClause
]
return Insert(" ".join(clauses.compactMap { $0 }).expression)
}

/// Runs an `INSERT` statement against the query with `DEFAULT VALUES`.
public func insert() -> Insert {
return Insert(" ".join([
Expand Down Expand Up @@ -1048,6 +1085,8 @@ extension Connection {
/// - SeeAlso: `QueryType.insert(value:_:)`
/// - SeeAlso: `QueryType.insert(values:)`
/// - SeeAlso: `QueryType.insert(or:_:)`
/// - SeeAlso: `QueryType.insertMany(values:)`
/// - SeeAlso: `QueryType.insertMany(or:_:)`
/// - SeeAlso: `QueryType.insert()`
///
/// - Parameter query: An insert query.
Expand Down
37 changes: 37 additions & 0 deletions Tests/SQLiteTests/QueryTests.swift
Original file line number Diff line number Diff line change
Expand Up @@ -247,6 +247,26 @@ class QueryTests : XCTestCase {
)
}

func test_insert_many_compilesInsertManyExpression() {
AssertSQL(
"INSERT INTO \"users\" (\"email\", \"age\") VALUES ('[email protected]', 30), ('[email protected]', 32), ('[email protected]', 83)",
users.insertMany([[email <- "[email protected]", age <- 30], [email <- "[email protected]", age <- 32], [email <- "[email protected]", age <- 83]])
)
}
func test_insert_many_compilesInsertManyNoneExpression() {
AssertSQL(
"INSERT INTO \"users\" DEFAULT VALUES",
users.insertMany([])
)
}

func test_insert_many_withOnConflict_compilesInsertManyOrOnConflictExpression() {
AssertSQL(
"INSERT OR REPLACE INTO \"users\" (\"email\", \"age\") VALUES ('[email protected]', 30), ('[email protected]', 32), ('[email protected]', 83)",
users.insertMany(or: .replace, [[email <- "[email protected]", age <- 30], [email <- "[email protected]", age <- 32], [email <- "[email protected]", age <- 83]])
)
}

func test_insert_encodable() throws {
let emails = Table("emails")
let value = TestCodable(int: 1, string: "2", bool: true, float: 3, double: 4, date: Date(timeIntervalSince1970: 0), optional: nil, sub: nil)
Expand Down Expand Up @@ -288,6 +308,18 @@ class QueryTests : XCTestCase {
)
}

func test_insert_many_encodable() throws {
let emails = Table("emails")
let value1 = TestCodable(int: 1, string: "2", bool: true, float: 3, double: 4, date: Date(timeIntervalSince1970: 0), optional: nil, sub: nil)
let value2 = TestCodable(int: 2, string: "3", bool: true, float: 3, double: 5, date: Date(timeIntervalSince1970: 0), optional: nil, sub: nil)
let value3 = TestCodable(int: 3, string: "4", bool: true, float: 3, double: 6, date: Date(timeIntervalSince1970: 0), optional: nil, sub: nil)
let insert = try emails.insertMany([value1, value2, value3])
AssertSQL(
"INSERT INTO \"emails\" (\"int\", \"string\", \"bool\", \"float\", \"double\", \"date\") VALUES (1, '2', 1, 3.0, 4.0, '1970-01-01T00:00:00.000'), (2, '3', 1, 3.0, 5.0, '1970-01-01T00:00:00.000'), (3, '4', 1, 3.0, 6.0, '1970-01-01T00:00:00.000')",
insert
)
}

func test_update_compilesUpdateExpression() {
AssertSQL(
"UPDATE \"users\" SET \"age\" = 30, \"admin\" = 1 WHERE (\"id\" = 1)",
Expand Down Expand Up @@ -505,6 +537,11 @@ class QueryIntegrationTests : SQLiteTestCase {
XCTAssertEqual(1, id)
}

func test_insert_many() {
let id = try! db.run(users.insertMany([[email <- "[email protected]"], [email <- "[email protected]"]]))
XCTAssertEqual(2, id)
}

func test_upsert() throws {
let fetchAge = { () throws -> Int? in
return try self.db.pluck(self.users.filter(self.email == "[email protected]")).flatMap { $0[self.age] }
Expand Down