Skip to content

Commit

Permalink
fix: EXPOSED-226 Upsert fails with only key columns in update (#1900)
Browse files Browse the repository at this point in the history
* fix: EXPOSED-226 Upsert fails with all key columns in update

If all columns in an upsert block are conflict/key columns and onUpdate is not
set, an empty update clause is generated, which throws an SQLException in all
databases except MySQL and MariaDB.

Including these key columns in the update clause is valid SQL in all databases
except Oracle, so filtering the update columns now only happens if the result
will not be an empty list.
  • Loading branch information
bog-walk authored Nov 27, 2023
1 parent bb2c933 commit c5caebb
Show file tree
Hide file tree
Showing 4 changed files with 47 additions and 3 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -539,7 +539,7 @@ abstract class FunctionProvider {
val autoIncColumn = table.autoIncColumn
val nextValExpression = autoIncColumn?.autoIncColumnType?.nextValExpression
val dataColumnsWithoutAutoInc = autoIncColumn?.let { dataColumns - autoIncColumn } ?: dataColumns
val updateColumns = dataColumns.filter { it !in keyColumns }
val updateColumns = dataColumns.filter { it !in keyColumns }.ifEmpty { dataColumns }

return with(QueryBuilder(true)) {
+"MERGE INTO "
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -249,7 +249,8 @@ internal object PostgreSQLFunctionProvider : FunctionProvider() {
transaction.throwUnsupportedException("UPSERT requires a unique key or constraint as a conflict target")
}

val updateColumns = data.unzip().first.filter { it !in keyColumns }
val dataColumns = data.unzip().first
val updateColumns = dataColumns.filter { it !in keyColumns }.ifEmpty { dataColumns }

return with(QueryBuilder(true)) {
appendInsertToUpsertClause(table, data, transaction)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -216,7 +216,8 @@ internal object SQLiteFunctionProvider : FunctionProvider() {
}

+" DO"
val updateColumns = data.unzip().first.filter { it !in keyColumns }
val dataColumns = data.unzip().first
val updateColumns = dataColumns.filter { it !in keyColumns }.ifEmpty { dataColumns }
appendUpdateToUpsertClause(table, updateColumns, onUpdate, transaction, isAliasNeeded = false)

where?.let {
Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
package org.jetbrains.exposed.sql.tests.shared.dml

import org.jetbrains.exposed.dao.id.IntIdTable
import org.jetbrains.exposed.exceptions.ExposedSQLException
import org.jetbrains.exposed.exceptions.UnsupportedByDialectException
import org.jetbrains.exposed.sql.*
import org.jetbrains.exposed.sql.SqlExpressionBuilder.concat
Expand All @@ -14,6 +15,7 @@ import org.jetbrains.exposed.sql.tests.shared.expectException
import org.junit.Test
import java.util.*
import kotlin.properties.Delegates
import kotlin.test.assertNotNull

// Upsert implementation does not support H2 version 1
// https://youtrack.jetbrains.com/issue/EXPOSED-30/Phase-Out-Support-for-H2-Version-1.x
Expand Down Expand Up @@ -86,6 +88,46 @@ class UpsertTests : DatabaseTestsBase() {
}
}

@Test
fun testUpsertWithAllColumnsInPK() {
val tester = object : Table("tester") {
val userId = varchar("user_id", 32)
val keyId = varchar("key_id", 32)
override val primaryKey = PrimaryKey(userId, keyId)
}

fun upsertOnlyKeyColumns(values: Pair<String, String>) {
tester.upsert {
it[userId] = values.first
it[keyId] = values.second
}
}

withTables(tester) { testDb ->
excludingH2Version1(testDb) {
val primaryKeyValues = Pair("User A", "Key A")
if (testDb == TestDB.ORACLE) {
// Oracle explicitly prohibits using key columns in update clause
// throws 'ORA-38104: Columns referenced in the ON Clause cannot be updated'
expectException<ExposedSQLException> {
upsertOnlyKeyColumns(primaryKeyValues)
}
} else {
// insert new row
upsertOnlyKeyColumns(primaryKeyValues)
// 'update' existing row to have identical values
upsertOnlyKeyColumns(primaryKeyValues)

val result = tester.selectAll().singleOrNull()
assertNotNull(result)

val resultValues = Pair(result[tester.userId], result[tester.keyId])
assertEquals(primaryKeyValues, resultValues)
}
}
}
}

@Test
fun testUpsertWithUniqueIndexConflict() {
withTables(Words) { testDb ->
Expand Down

0 comments on commit c5caebb

Please sign in to comment.