Skip to content

Commit

Permalink
Support for UPSERT/conflict resolution clauses (#90)
Browse files Browse the repository at this point in the history
* Add SQL dialect property to specify supported upsert syntax. Add SQLColumnAssignment, SQLConflictAction, and SQLExcludedColumn. Add conflict action and target properties to SQLInsert and teach it how to serialize them.

* Factor column assignments out of SQLUpdateBuilder into SQLColumnUpdateBuilder protocol. Add SQLConflictUpdateBuilder. Add methods to specify conflict handling to SQLInsertBuilder.

* Create `SQLConflictResolutionStrategy` to encapsulate upsert handling, including an additional helper expression to serve as a signpost for the single case where MySQL's syntax made it impossible to implement this with any consistency to how every single other thing in SQLKit works. There are fewer ambiguities about what happens in various scenarios (still could use some clarification). Updated SQLInsert and SQLInsertBuilder.

* Clean up and fix SQLBenchmark so all the tests can be enabled and used, and also clean up the SQLKit unit tests

* Add unit and integration tests for the upsert functionality. Note that the SQLBenchmark tests use Unicode code points from the supplemental plane and will not pass against a MySQL 5.7 database unless it has been explicitly configured to use the utf8mb4_unicode_520_ci collation (MySQL 8.0 supports a much newer collation by default).
  • Loading branch information
gwynne authored Oct 22, 2021
1 parent 8016882 commit 64eff0a
Show file tree
Hide file tree
Showing 19 changed files with 746 additions and 170 deletions.
41 changes: 41 additions & 0 deletions Sources/SQLKit/Builders/SQLColumnUpdateBuilder.swift
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
/// Builds column value assignment pairs for `UPDATE` queries.
///
/// builder.set("name", to: "Earth")
public protocol SQLColumnUpdateBuilder: AnyObject {
/// List of assignment pairs that have been built.
var values: [SQLExpression] { get set }
}

extension SQLColumnUpdateBuilder {
/// Encodes the given `Encodable` value to a sequence of key-value pairs and adds an assignment
/// for each pair.
@discardableResult
public func set<E>(model: E) throws -> Self where E: Encodable {
return try SQLQueryEncoder().encode(model).reduce(self) { $0.set(SQLColumn($1.0), to: $1.1) }
}

/// Add an assignment of the column with the given name to the provided bound value.
@discardableResult
public func set(_ column: String, to bind: Encodable) -> Self {
return self.set(SQLColumn(column), to: SQLBind(bind))
}

/// Add an assignment of the column with the given name to the given expression.
@discardableResult
public func set(_ column: String, to value: SQLExpression) -> Self {
return self.set(SQLColumn(column), to: value)
}

/// Add an assignment of the given column to the provided bound value.
@discardableResult
public func set(_ column: SQLExpression, to bind: Encodable) -> Self {
return self.set(column, to: SQLBind(bind))
}

/// Add an assignment of the given column to the given expression.
@discardableResult
public func set(_ column: SQLExpression, to value: SQLExpression) -> Self {
self.values.append(SQLBinaryExpression(left: column, op: SQLBinaryOperator.equal, right: value))
return self
}
}
38 changes: 38 additions & 0 deletions Sources/SQLKit/Builders/SQLConflictUpdateBuilder.swift
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
/// A builder for specifying column updates and an optional predicate to be applied to
/// rows that caused unique key conflicts during an `INSERT`.
public final class SQLConflictUpdateBuilder: SQLColumnUpdateBuilder, SQLPredicateBuilder {
// See `SQLColumnUpdateBuilder.values`.
public var values: [SQLExpression]

// See `SQLPredicateBuilder.predicate`.
public var predicate: SQLExpression?

/// Create a conflict update builder.
internal init() {
self.values = []
self.predicate = nil
}

/// Add an assignment of the column with the given name, using the value the column was
/// given in the `INSERT` query's `VALUES` list. See `SQLExcludedColumn`.
@discardableResult
public func set(excludedValueOf columnName: String) -> Self {
return self.set(excludedValueOf: SQLColumn(columnName))
}

/// Add an assignment of the given column, using the value the column was given in the
/// `INSERT` query's `VALUES` list. See `SQLExcludedColumn`.
@discardableResult
public func set(excludedValueOf column: SQLExpression) -> Self {
self.values.append(SQLColumnAssignment(settingExcludedValueFor: column))
return self
}

/// Encodes the given `Encodable` value to a sequence of key-value pairs and adds an assignment
/// for each pair which uses the values each column was given in the original `INSERT` query's
/// `VALUES` list. See `SQLExcludedColumn`.
@discardableResult
public func set<E>(excludedContentOf model: E) throws -> Self where E: Encodable {
return try SQLQueryEncoder().encode(model).reduce(self) { $0.set(excludedValueOf: $1.0) }
}
}
45 changes: 45 additions & 0 deletions Sources/SQLKit/Builders/SQLInsertBuilder.swift
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,51 @@ public final class SQLInsertBuilder: SQLQueryBuilder, SQLReturningBuilder {
self.insert.values.append(values)
return self
}

@discardableResult
public func ignoringConflicts(with targetColumn: String) -> Self {
self.ignoringConflicts(with: [targetColumn])
}

@discardableResult
public func ignoringConflicts(with targetColumns: [String] = []) -> Self {
self.insert.conflictStrategy = .init(targets: targetColumns, action: .noAction)
return self
}

@discardableResult
public func ignoringConflicts(with targetColumns: [SQLExpression]) -> Self {
self.insert.conflictStrategy = .init(targets: targetColumns, action: .noAction)
return self
}

@discardableResult
public func onConflict(
with targetColumn: String,
`do` updatePredicate: (SQLConflictUpdateBuilder) throws -> SQLConflictUpdateBuilder
) rethrows -> Self {
try self.onConflict(with: [targetColumn], do: updatePredicate)
}

@discardableResult
public func onConflict(
with targetColumns: [String] = [],
`do` updatePredicate: (SQLConflictUpdateBuilder) throws -> SQLConflictUpdateBuilder
) rethrows -> Self {
try self.onConflict(with: targetColumns.map { SQLColumn($0) }, do: updatePredicate)
}

@discardableResult
public func onConflict(
with targetColumns: [SQLExpression],
`do` updatePredicate: (SQLConflictUpdateBuilder) throws -> SQLConflictUpdateBuilder
) rethrows -> Self {
let conflictBuilder = SQLConflictUpdateBuilder()
_ = try updatePredicate(conflictBuilder)

self.insert.conflictStrategy = .init(targets: targetColumns, action: .update(assignments: conflictBuilder.values, predicate: conflictBuilder.predicate))
return self
}
}

// MARK: Connection
Expand Down
32 changes: 7 additions & 25 deletions Sources/SQLKit/Builders/SQLUpdateBuilder.swift
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@
/// .run()
///
/// See `SQLQueryBuilder` and `SQLPredicateBuilder` for more information.
public final class SQLUpdateBuilder: SQLQueryBuilder, SQLPredicateBuilder, SQLReturningBuilder {
public final class SQLUpdateBuilder: SQLQueryBuilder, SQLPredicateBuilder, SQLReturningBuilder, SQLColumnUpdateBuilder {
/// `Update` query being built.
public var update: SQLUpdate

Expand All @@ -15,6 +15,11 @@ public final class SQLUpdateBuilder: SQLQueryBuilder, SQLPredicateBuilder, SQLRe
public var query: SQLExpression {
return self.update
}

public var values: [SQLExpression] {
get { return self.update.values }
set { self.update.values = newValue }
}

public var predicate: SQLExpression? {
get { return self.update.predicate }
Expand All @@ -26,34 +31,11 @@ public final class SQLUpdateBuilder: SQLQueryBuilder, SQLPredicateBuilder, SQLRe
set { self.update.returning = newValue }
}

/// Creates a new `SQLDeleteBuilder`.
/// Creates a new `SQLUpdateBuilder`.
public init(_ update: SQLUpdate, on database: SQLDatabase) {
self.update = update
self.database = database
}

@discardableResult
public func set<E>(model: E) throws -> Self where E: Encodable {
let row = try SQLQueryEncoder().encode(model)
row.forEach { column, value in
_ = self.set(SQLColumn(column), to: value)
}
return self
}

/// Sets a column (specified by an identifier) to an expression.
@discardableResult
public func set(_ column: String, to bind: Encodable) -> Self {
return self.set(SQLIdentifier(column), to: SQLBind(bind))
}

/// Sets a column (specified by an identifier) to an expression.
@discardableResult
public func set(_ column: SQLExpression, to value: SQLExpression) -> Self {
let binary = SQLBinaryExpression(left: column, op: SQLBinaryOperator.equal, right: value)
update.values.append(binary)
return self
}
}

// MARK: Connection
Expand Down
54 changes: 54 additions & 0 deletions Sources/SQLKit/Query/SQLColumnAssignment.swift
Original file line number Diff line number Diff line change
@@ -0,0 +1,54 @@
/// Encapsulates a `col_name=value` expression in the context of an `UPDATE` query's value
/// assignment list. This is distinct from an `SQLBinaryExpression` using the `.equal`
/// operator in that the left side must be an _unqualified_ column name, the operator must
/// be `=`, and the right side may use `SQLExcludedColumn` when the assignment appears in
/// the `assignments` list of a `SQLConflictAction.update` specification.
public struct SQLColumnAssignment: SQLExpression {
/// The name of the column to assign.
public var columnName: SQLExpression

/// The value to assign.
public var value: SQLExpression

/// Create a column assignment from a column identifier and value expression.
public init(setting columnName: SQLExpression, to value: SQLExpression) {
self.columnName = columnName
self.value = value
}

/// Create a column assignment from a column identifier and value binding.
public init(setting columnName: SQLExpression, to value: Encodable) {
self.init(setting: columnName, to: SQLBind(value))
}

/// Create a column assignment from a column name and value binding.
public init(setting columnName: String, to value: Encodable) {
self.init(setting: columnName, to: SQLBind(value))
}

/// Create a column assignment from a column name and value expression.
public init(setting columnName: String, to value: SQLExpression) {
self.init(setting: SQLColumn(columnName), to: value)
}

/// Create a column assignment from a column name and using the excluded value
/// from an upsert's values list. See `SQLExcludedColumn`.
public init(settingExcludedValueFor columnName: String) {
self.init(settingExcludedValueFor: SQLColumn(columnName))
}

/// Create a column assignment from a column identifier and using the excluded value
/// from an upsert's values list. See `SQLExcludedColumn`.
public init(settingExcludedValueFor column: SQLExpression) {
self.init(setting: column, to: SQLExcludedColumn(column))
}

/// See `SQLExpression.serialize(to:)`.
public func serialize(to serializer: inout SQLSerializer) {
serializer.statement {
$0.append(self.columnName)
$0.append("=") // do not use SQLBinaryOperator.equal, which may be `==` in some dialects
$0.append(self.value)
}
}
}
19 changes: 19 additions & 0 deletions Sources/SQLKit/Query/SQLColumnDefinition.swift
Original file line number Diff line number Diff line change
Expand Up @@ -25,3 +25,22 @@ public struct SQLColumnDefinition: SQLExpression {
}
}
}

extension SQLColumnDefinition {
/// Create a new column definition from a string, data type, and array of constraints.
///
/// Turns this:
/// ```swift
/// SQLColumnDefinition(
/// column: SQLIdentifier("id"),
/// dataType: SQLDataType.bigInt,
/// constraints: [SQLColumnConstraintAlgorithm.primaryKey, SQLColumnConstraintAlgorithm.notNull]
/// )
/// ```
/// into this:
///
/// `SQLColumnDefinition("id", dataType: .bigint, constraints: [.primaryKey, .notNull]`
public init(_ name: String, dataType: SQLDataType, constraints: [SQLColumnConstraintAlgorithm] = []) {
self.init(column: SQLIdentifier(name), dataType: dataType, constraints: constraints)
}
}
24 changes: 24 additions & 0 deletions Sources/SQLKit/Query/SQLConflictAction.swift
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
/// An action to take when an `INSERT` query encounters a unique constraint violation.
///
/// - Note: This is one of the only types at this layer which is _not_ an `SQLExpression`.
/// This is down to the unfortunate fact that while PostgreSQL and SQLite both support the
/// standard's straightforward `ON CONFLICT DO NOTHING` syntax which goes in the same place
/// in the query as an update action would, MySQL can only express the `noAction` case
/// with `INSERT IGNORE`. This requires considering the conflict action twice in the same
/// query when serializing, and to decide what to emit in either location based on both
/// the specific action _and_ the dialect's supported snytax. As a result, the logic for
/// this has to live in `SQLInsert`, and it is not possible to serialize a conflict action
/// to SQL in isolation (but again, _only_ because MySQL couldn't be bothered), and this
/// enum can not conform to `SQLExpression`.
public enum SQLConflictAction {
/// Specifies that conflicts this action is applied to should be ignored, allowing the query to complete
/// successfully without inserting any new rows or changing any existing rows.
case noAction

/// Specifies that conflicts this action is applied to shall cause the INSERT to be converted to an UPDATE
/// on the same schema which performs the column updates specified by the associated column assignments and,
/// where supported by the database, constrained by the associated predicate. The column assignments may
/// include `SQLExcludedColumn` expressions to refer to values which would have been inserted into the row
/// if the conflict had not taken place.
case update(assignments: [SQLExpression], predicate: SQLExpression?)
}
86 changes: 86 additions & 0 deletions Sources/SQLKit/Query/SQLConflictResolutionStrategy.swift
Original file line number Diff line number Diff line change
@@ -0,0 +1,86 @@
/// Specifies a conflict resolution strategy and associated conditions for an `INSERT` query.
/// An `INSERT` with a conflict strategy is often refered to as an `UPSERT` ("insert or update").
/// Databases are not required to support any given subset of upsert functionality, or any at all.
///
/// Unfortunately, in MySQL the "no action" strategy must use `INSERT IGNORE`, which appears in a
/// completely different place in the query than the update strategy. For now, this is implemented
/// by providing an additional expression that `SQLInsert` has to embed at the appropriate point
/// if provided, which is gated on both the dialect's syntax and the conflict action. There hasn't
/// been a need to deal with this particular kind of syntax issue before, so this method of handling
/// it is something of an experiment.
public struct SQLConflictResolutionStrategy: SQLExpression {
/// The column or columns which comprise the uniquness constraint to which the strategy
/// should apply. The exact rules for how a matching constraint is found when an exact
/// match is not found vary between databases. Not all database implement conflict targets.
public var targetColumns: [SQLExpression]

/// An action to take to resolve a conflict in the unique index.
public var action: SQLConflictAction

/// Create a resolution strategy over the given column name and an action.
public init(target targetColumn: String, action: SQLConflictAction) {
self.init(targets: [targetColumn], action: action)
}

/// Create a resolution strategy over the given column names and an action.
public init(targets targetColumns: [String], action: SQLConflictAction) {
self.init(targets: targetColumns.map { SQLColumn($0) }, action: action)
}

/// Create a resolution strategy over the given column and an action.
public init(target targetColumn: SQLExpression, action: SQLConflictAction) {
self.init(targets: [targetColumn], action: action)
}

/// Create a resolution strategy over the given columns and an action.
public init(targets targetColumns: [SQLExpression], action: SQLConflictAction) {
self.targetColumns = targetColumns
self.action = action
}

/// An expression to be embedded into the same `INSERT` query as the strategy expression to
/// work around MySQL's desire to make life difficult.
public func queryModifier(for serializer: SQLSerializer) -> SQLExpression? {
if serializer.dialect.upsertSyntax == .mysqlLike, case .noAction = self.action {
return SQLInsertModifier()
}
return nil
}

// See `SQLSerializer.serialize(to:)`.
public func serialize(to serializer: inout SQLSerializer) {
serializer.statement {
switch ($0.dialect.upsertSyntax, self.action) {
case (.standard, .noAction):
$0.append("ON CONFLICT")
if !self.targetColumns.isEmpty {
$0.append(SQLGroupExpression(self.targetColumns))
}
$0.append("DO NOTHING")
case (.standard, .update(let assignments, let predicate)):
assert(!assignments.isEmpty, "Must specify at least one column for updates; consider using noAction instead.")
$0.append("ON CONFLICT")
if !self.targetColumns.isEmpty {
$0.append(SQLGroupExpression(self.targetColumns))
}
$0.append("DO UPDATE SET", SQLList(assignments))
if let predicate = predicate { $0.append("WHERE", predicate) }
case (.mysqlLike, .noAction):
break
case (.mysqlLike, .update(let assignments, _)):
assert(!assignments.isEmpty, "Must specify at least one column for updates; consider using noAction instead.")
$0.append("ON DUPLICATE KEY UPDATE", SQLList(assignments))
case (.unsupported, _):
break
}
}
}
}

/// Simple helper for working around MySQL's refusal to implement standard SQL. Only emits SQL when needed.
public struct SQLInsertModifier: SQLExpression {
// See `SQLSerializer.serialize(to:)`.
public func serialize(to serializer: inout SQLSerializer) {
serializer.write("IGNORE")
}
}
Loading

0 comments on commit 64eff0a

Please sign in to comment.