From d454ff22b4d2dce4aa45a874d267677c70364e6f Mon Sep 17 00:00:00 2001 From: Jocelyne Date: Mon, 31 Jul 2023 16:42:29 +0200 Subject: [PATCH] feat: Add support for changing default value in SQL Server 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. --- .../org/jetbrains/exposed/sql/Column.kt | 11 ++++++- .../exposed/sql/vendors/SQLServerDialect.kt | 32 +++++++++++++++++-- .../jetbrains/exposed/JodaTimeDefaultsTest.kt | 20 +++++++----- .../ddl/CreateMissingTablesAndColumnsTests.kt | 7 ++-- 4 files changed, 54 insertions(+), 16 deletions(-) diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Column.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Column.kt index c7a5362afb..a1c41df6af 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Column.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Column.kt @@ -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 @@ -112,7 +113,15 @@ class Column( } 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 = column.table.tableName + val columnName = column.name + val constraintName = "DF_${tableName}_$columnName" + append(" CONSTRAINT $constraintName DEFAULT $expressionSQL") + } else { + append(" DEFAULT $expressionSQL") + } } } diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt index 2d5e03968f..df28066b1c 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLServerDialect.kt @@ -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 = - 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()}" @@ -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" } diff --git a/exposed-jodatime/src/test/kotlin/org/jetbrains/exposed/JodaTimeDefaultsTest.kt b/exposed-jodatime/src/test/kotlin/org/jetbrains/exposed/JodaTimeDefaultsTest.kt index 971c264b7f..ac8d0fbb0d 100644 --- a/exposed-jodatime/src/test/kotlin/org/jetbrains/exposed/JodaTimeDefaultsTest.kt +++ b/exposed-jodatime/src/test/kotlin/org/jetbrains/exposed/JodaTimeDefaultsTest.kt @@ -172,6 +172,10 @@ class JodaTimeDefaultsTest : JodaTimeBaseTest() { else -> "NULL" } + fun constraintNamePart(columnName: String) = (currentDialect as? SQLServerDialect)?.let { + " CONSTRAINT DF_t_$columnName" + } ?: "" + withTables(listOf(TestDB.SQLITE), testTable) { val dtType = currentDialectTest.dataTypeProvider.dateTimeType() val varCharType = currentDialectTest.dataTypeProvider.varcharType(100) @@ -179,14 +183,14 @@ class JodaTimeDefaultsTest : JodaTimeBaseTest() { val baseExpression = "CREATE TABLE " + addIfNotExistsIfSupported() + "${"t".inProperCase()} (" + "${"id".inProperCase()} ${currentDialectTest.dataTypeProvider.integerAutoincType()} PRIMARY KEY, " + - "${"s".inProperCase()} $varCharType DEFAULT 'test' NOT NULL, " + - "${"sn".inProperCase()} $varCharType DEFAULT 'testNullable' NULL, " + - "${"l".inProperCase()} ${currentDialectTest.dataTypeProvider.longType()} DEFAULT 42 NOT NULL, " + - "$q${"c".inProperCase()}$q CHAR DEFAULT 'X' NOT NULL, " + - "${"t1".inProperCase()} $dtType ${currentDT.itOrNull()}, " + - "${"t2".inProperCase()} $dtType ${nowExpression.itOrNull()}, " + - "${"t3".inProperCase()} $dtType ${dtLiteral.itOrNull()}, " + - "${"t4".inProperCase()} DATE ${dtLiteral.itOrNull()}" + + "${"s".inProperCase()} $varCharType${constraintNamePart("s")} DEFAULT 'test' NOT NULL, " + + "${"sn".inProperCase()} $varCharType${constraintNamePart("sn")} DEFAULT 'testNullable' NULL, " + + "${"l".inProperCase()} ${currentDialectTest.dataTypeProvider.longType()}${constraintNamePart("l")} DEFAULT 42 NOT NULL, " + + "$q${"c".inProperCase()}$q CHAR${constraintNamePart("c")} DEFAULT 'X' NOT NULL, " + + "${"t1".inProperCase()} $dtType${constraintNamePart("t1")} ${currentDT.itOrNull()}, " + + "${"t2".inProperCase()} $dtType${constraintNamePart("t2")} ${nowExpression.itOrNull()}, " + + "${"t3".inProperCase()} $dtType${constraintNamePart("t3")} ${dtLiteral.itOrNull()}, " + + "${"t4".inProperCase()} DATE${constraintNamePart("t4")} ${dtLiteral.itOrNull()}" + ")" val expected = if (currentDialectTest is OracleDialect || currentDialectTest.h2Mode == H2Dialect.H2CompatibilityMode.Oracle) { diff --git a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/ddl/CreateMissingTablesAndColumnsTests.kt b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/ddl/CreateMissingTablesAndColumnsTests.kt index c85d1b1120..641a50b731 100644 --- a/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/ddl/CreateMissingTablesAndColumnsTests.kt +++ b/exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/ddl/CreateMissingTablesAndColumnsTests.kt @@ -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 { @@ -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)