Skip to content

Commit

Permalink
fix: EXPOSED-551 [SQL Server] Update from join with limit throws synt…
Browse files Browse the repository at this point in the history
…ax exception

Attempting to perform an update from a join, with a provided limit, throws a syntax
exception if either SQL Server or MySQL is used. The former because of an error in
generated SQL and the latter because it is not allowed (when it should fail early).
  • Loading branch information
bog-walk committed Sep 18, 2024
1 parent 8f8499c commit 8de51ad
Show file tree
Hide file tree
Showing 4 changed files with 51 additions and 14 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,17 @@ internal object MariaDBFunctionProvider : MysqlFunctionProvider() {
append("LOCATE(\'", substring, "\',", expr, ")")
}

override fun update(
targets: Join,
columnsAndValues: List<Pair<Column<*>, Any?>>,
limit: Int?,
where: Op<Boolean>?,
transaction: Transaction
): String {
val sql = super.update(targets, columnsAndValues, null, where, transaction)
return if (limit != null) "$sql LIMIT $limit" else sql
}

override fun explain(
analyze: Boolean,
options: String?,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -219,21 +219,26 @@ internal open class MysqlFunctionProvider : FunctionProvider() {
limit: Int?,
where: Op<Boolean>?,
transaction: Transaction
): String = with(QueryBuilder(true)) {
+"UPDATE "
targets.describe(transaction, this)
+" SET "
columnsAndValues.appendTo(this) { (col, value) ->
append("${transaction.fullIdentity(col)}=")
registerArgument(col, value)
): String {
if (limit != null) {
transaction.throwUnsupportedException("MySQL doesn't support LIMIT in UPDATE with join clause.")
}

where?.let {
+" WHERE "
+it
return with(QueryBuilder(true)) {
+"UPDATE "
targets.describe(transaction, this)
+" SET "
columnsAndValues.appendTo(this) { (col, value) ->
append("${transaction.fullIdentity(col)}=")
registerArgument(col, value)
}

where?.let {
+" WHERE "
+it
}
toString()
}
limit?.let { +" LIMIT $it" }
toString()
}

override fun upsert(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -212,7 +212,7 @@ internal object SQLServerFunctionProvider : FunctionProvider() {

targets.checkJoinTypes(StatementType.UPDATE)
if (limit != null) {
+"UPDATE TOP($limit)"
+"UPDATE TOP($limit) "
} else {
+"UPDATE "
}
Expand All @@ -229,7 +229,6 @@ internal object SQLServerFunctionProvider : FunctionProvider() {
+" AND "
+it
}
limit?.let { +" LIMIT $it" }
toString()
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ import org.jetbrains.exposed.sql.tests.shared.assertEquals
import org.jetbrains.exposed.sql.tests.shared.expectException
import org.jetbrains.exposed.sql.vendors.SQLiteDialect
import org.junit.Test
import kotlin.test.assertTrue

class UpdateTests : DatabaseTestsBase() {
private val notSupportLimit by lazy {
Expand Down Expand Up @@ -95,6 +96,27 @@ class UpdateTests : DatabaseTestsBase() {
}
}

@Test
fun testUpdateWithJoinAndLimit() {
val supportsUpdateWithJoinAndLimit = TestDB.ALL_MARIADB + TestDB.ORACLE + TestDB.SQLSERVER
withCitiesAndUsers(exclude = TestDB.ALL - supportsUpdateWithJoinAndLimit) { _, users, userData ->
val join = users.innerJoin(userData)

val maxToUpdate = 2
assertTrue { join.selectAll().count() > maxToUpdate }

val updatedValue = 123
val valueQuery = join.selectAll().where { userData.value eq updatedValue }
assertEquals(0, valueQuery.count())

join.update(limit = 2) {
it[userData.value] = 123
}

assertEquals(2, valueQuery.count())
}
}

@Test
fun testUpdateWithMultipleJoins() {
withCitiesAndUsers(exclude = TestDB.ALL_H2 + TestDB.SQLITE) { cities, users, userData ->
Expand Down

0 comments on commit 8de51ad

Please sign in to comment.