Skip to content

Commit

Permalink
feat: Add support for changing default value in SQL Server
Browse files Browse the repository at this point in the history
When creating a column with a DEFAULT value in SQL Server, a DEFAULT constraint is created under the hood. To modify the default value of a column, the constraint has to be dropped first. To do that, the name of the constraint is needed. To be able to obtain its name easily, the way the DEFAULT constraint is created was modified to give it an explicit name with the format DF_TableName_ColumnName. So when adding a new DEFAULT value to a column or modifying an existing one, it's necessary to drop the existing DEFAULT constraint first, and then add a new one.
  • Loading branch information
joc-a committed Aug 8, 2023
1 parent 96c8be7 commit de0c2d7
Show file tree
Hide file tree
Showing 3 changed files with 42 additions and 9 deletions.
12 changes: 10 additions & 2 deletions exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Column.kt
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@ package org.jetbrains.exposed.sql
import org.jetbrains.exposed.exceptions.throwUnsupportedException
import org.jetbrains.exposed.sql.transactions.TransactionManager
import org.jetbrains.exposed.sql.vendors.H2Dialect
import org.jetbrains.exposed.sql.vendors.SQLServerDialect
import org.jetbrains.exposed.sql.vendors.SQLiteDialect
import org.jetbrains.exposed.sql.vendors.currentDialect
import org.jetbrains.exposed.sql.vendors.inProperCase
Expand Down Expand Up @@ -85,7 +86,8 @@ class Column<T>(
fun descriptionDdl(modify: Boolean = false): String = buildString {
val tr = TransactionManager.current()
val column = this@Column
append(tr.identity(column))
val columnName = tr.identity(column)
append(columnName)
append(" ")
val isPKColumn = table.primaryKey?.columns?.contains(column) == true
val isSQLiteAutoIncColumn = currentDialect is SQLiteDialect && columnType.isAutoInc
Expand All @@ -112,7 +114,13 @@ class Column<T>(
}
exposedLogger.error("${currentDialect.name} ${tr.db.version} doesn't support expression '$expressionSQL' as default value.$clientDefault")
} else {
append(" DEFAULT $expressionSQL")
if (currentDialect is SQLServerDialect) {
// Create a DEFAULT constraint with an explicit name to facilitate removing it later if needed
val tableName = tr.identity(column.table)
append(" CONSTRAINT DF_${tableName}_$columnName DEFAULT $expressionSQL")
} else {
append(" DEFAULT $expressionSQL")
}
}
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -251,9 +251,29 @@ open class SQLServerDialect : VendorDialect(dialectName, SQLServerDataTypeProvid
return columnDefault !in nonAcceptableDefaults
}

// EXPOSED-85 Fix changing default value on column in SQL Server as it requires to drop/create constraint
override fun modifyColumn(column: Column<*>, columnDiff: ColumnDiff): List<String> =
super.modifyColumn(column, columnDiff).map { it.replace("MODIFY COLUMN", "ALTER COLUMN") }
super.modifyColumn(column, columnDiff).map { statement ->
if (columnDiff.defaults) {
val transaction = TransactionManager.current()
val tableName = transaction.identity(column.table)
val colName = transaction.identity(column)

val dropConstraint = "DROP CONSTRAINT IF EXISTS DF_${tableName}_$colName"

column.dbDefaultValue?.let {
buildString {
append(statement.substringBefore("MODIFY COLUMN") + dropConstraint)
append("; ")
append(
statement.substringBefore("MODIFY COLUMN") +
"ADD CONSTRAINT DF_${tableName}_$colName DEFAULT ${SQLServerDataTypeProvider.processForDefaultValue(it)} for $colName"
)
}
} ?: (statement.substringBefore("MODIFY COLUMN") + dropConstraint)
} else {
statement.replace("MODIFY COLUMN", "ALTER COLUMN")
}
}

override fun createDatabase(name: String): String = "CREATE DATABASE ${name.inProperCase()}"

Expand Down Expand Up @@ -284,7 +304,13 @@ open class SQLServerDialect : VendorDialect(dialectName, SQLServerDataTypeProvid
return super.createIndex(index)
}

override fun createIndexWithType(name: String, table: String, columns: String, type: String, filterCondition: String): String {
override fun createIndexWithType(
name: String,
table: String,
columns: String,
type: String,
filterCondition: String
): String {
return "CREATE $type INDEX $name ON $table $columns$filterCondition"
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -355,9 +355,8 @@ class CreateMissingTablesAndColumnsTests : DatabaseTestsBase() {
val actual = SchemaUtils.statementsRequiredToActualizeScheme(emptyTable)
assertEquals(1, actual.size)

// SQL Server requires drop/create constraint to change defaults, unsupported for now
// Oracle treat '' as NULL column and can't alter from NULL to NULL
if (testDb !in listOf(TestDB.SQLSERVER, TestDB.ORACLE)) {
if (testDb != TestDB.ORACLE) {
// Apply changes
actual.forEach { exec(it) }
} else {
Expand Down Expand Up @@ -399,8 +398,8 @@ class CreateMissingTablesAndColumnsTests : DatabaseTestsBase() {
override val primaryKey = PrimaryKey(id)
}

val excludeSettings = listOf(TestDB.SQLITE, TestDB.SQLSERVER)
val complexAlterTable = listOf(TestDB.POSTGRESQL, TestDB.POSTGRESQLNG, TestDB.ORACLE, TestDB.H2_PSQL)
val excludeSettings = listOf(TestDB.SQLITE)
val complexAlterTable = listOf(TestDB.POSTGRESQL, TestDB.POSTGRESQLNG, TestDB.ORACLE, TestDB.H2_PSQL, TestDB.SQLSERVER)
withDb(excludeSettings = excludeSettings) { testDb ->
try {
SchemaUtils.createMissingTablesAndColumns(t1)
Expand Down

0 comments on commit de0c2d7

Please sign in to comment.