Skip to content

Commit

Permalink
chore!: Change H2 Oracle longType and longAutoincType from NUMBER(19)…
Browse files Browse the repository at this point in the history
… to BIGINT and add CHECK constraint in Oracle and SQLite
  • Loading branch information
joc-a committed Oct 14, 2024
1 parent b0a7aed commit d2cf30f
Show file tree
Hide file tree
Showing 7 changed files with 92 additions and 9 deletions.
2 changes: 2 additions & 0 deletions documentation-website/Writerside/topics/Breaking-Changes.md
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,8 @@
* In Oracle and H2 Oracle, the `uinteger()` column now maps to data type `NUMBER(10)` instead of `NUMBER(13)`.
* In Oracle and H2 Oracle, the `integer()` column now maps to data type `NUMBER(10)` and `INTEGER` respectively, instead of `NUMBER(12)`.
In Oracle and SQLite, using the integer column in a table now also creates a CHECK constraint to ensure that no out-of-range values are inserted.
* In H2 Oracle, the `long()` column now maps to data type `BIGINT` instead of `NUMBER(19)`.
In Oracle and SQLite, using the long column in a table now also creates a CHECK constraint to ensure that no out-of-range values are inserted.

## 0.55.0
* The `DeleteStatement` property `table` is now deprecated in favor of `targetsSet`, which holds a `ColumnSet` that may be a `Table` or `Join`.
Expand Down
36 changes: 35 additions & 1 deletion exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Table.kt
Original file line number Diff line number Diff line change
Expand Up @@ -1658,6 +1658,11 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
append("IF NOT EXISTS ")
}
append(TransactionManager.current().identity(this@Table))

// Add CHECK constraint to Long columns in Oracle and SQLite.
// It is done here because special handling is necessary based on the dialect.
addLongColumnCheckConstraintIfNeeded()

if (columns.isNotEmpty()) {
columns.joinTo(this, prefix = " (") { column ->
column.descriptionDdl(false)
Expand Down Expand Up @@ -1698,7 +1703,8 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
}.let {
if (currentDialect !is SQLiteDialect && currentDialect !is OracleDialect) {
it.filterNot { (name, _) ->
name.startsWith("${generatedSignedCheckPrefix}integer")
name.startsWith("${generatedSignedCheckPrefix}integer") ||
name.startsWith("${generatedSignedCheckPrefix}long")
}
} else {
it
Expand All @@ -1723,6 +1729,34 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
return createAutoIncColumnSequence() + createTable + createConstraint
}

private fun addLongColumnCheckConstraintIfNeeded() {
if (currentDialect is OracleDialect || currentDialect is SQLiteDialect) {
columns.filter { it.columnType is LongColumnType }.forEach { column ->
val name = column.name
val checkName = "${generatedSignedCheckPrefix}long_$name"
if (checkConstraints.none { it.first == checkName }) {
column.check(checkName) {
if (currentDialect is SQLiteDialect) {
fun typeOf(value: String) = object : ExpressionWithColumnType<String>() {
override fun toQueryBuilder(queryBuilder: QueryBuilder) = queryBuilder { append("typeof($value)") }
override val columnType: IColumnType<String> = TextColumnType()
}

val typeCondition = Expression.build { typeOf(name) eq stringLiteral("integer") }
if (column.columnType.nullable) {
column.isNull() or typeCondition
} else {
typeCondition
}
} else {
it.between(Long.MIN_VALUE, Long.MAX_VALUE)
}
}
}
}
}
}

private fun createAutoIncColumnSequence(): List<String> {
return autoIncColumn?.autoIncColumnType?.sequence?.createStatement().orEmpty()
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -33,8 +33,12 @@ internal object OracleDataTypeProvider : DataTypeProvider() {
override fun integerAutoincType(): String = integerType()
override fun uintegerType(): String = "NUMBER(10)"
override fun uintegerAutoincType(): String = "NUMBER(10)"
override fun longType(): String = "NUMBER(19)"
override fun longAutoincType(): String = "NUMBER(19)"
override fun longType(): String = if (currentDialect.h2Mode == H2Dialect.H2CompatibilityMode.Oracle) {
"BIGINT"
} else {
"NUMBER(19)"
}
override fun longAutoincType(): String = longType()
override fun ulongType(): String = "NUMBER(20)"
override fun ulongAutoincType(): String = "NUMBER(20)"
override fun varcharType(colLength: Int): String = "VARCHAR2($colLength CHAR)"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -273,8 +273,12 @@ class DefaultsTest : DatabaseTestsBase() {
"${"t9".inProperCase()} $timeType${testTable.t9.constraintNamePart()} ${tLiteral.itOrNull()}, " +
"${"t10".inProperCase()} $timeType${testTable.t10.constraintNamePart()} ${tLiteral.itOrNull()}" +
when (testDb) {
TestDB.SQLITE, TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
else -> ""
} +
")"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -209,8 +209,12 @@ class JodaTimeDefaultsTest : DatabaseTestsBase() {
"${"t5".inProperCase()} $timeType${testTable.t5.constraintNamePart()} ${tLiteral.itOrNull()}, " +
"${"t6".inProperCase()} $timeType${testTable.t6.constraintNamePart()} ${tLiteral.itOrNull()}" +
when (testDb) {
TestDB.SQLITE, TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
else -> ""
} +
")"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -270,8 +270,12 @@ class DefaultsTest : DatabaseTestsBase() {
"${"t9".inProperCase()} $timeType${testTable.t9.constraintNamePart()} ${tLiteral.itOrNull()}, " +
"${"t10".inProperCase()} $timeType${testTable.t10.constraintNamePart()} ${tLiteral.itOrNull()}" +
when (testDb) {
TestDB.SQLITE, TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
TestDB.ORACLE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
else -> ""
} +
")"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -104,4 +104,35 @@ class NumericColumnTypesTests : DatabaseTestsBase() {
}
}
}

@Test
fun testLongAcceptsOnlyAllowedRange() {
val testTable = object : Table("test_table") {
val long = long("long_column")
}

withTables(testTable) { testDb ->
val columnName = testTable.long.nameInDatabaseCase()
val ddlEnding = when (testDb) {
TestDB.SQLITE -> "CHECK (typeof($columnName) = 'integer'))"
TestDB.ORACLE -> "CHECK ($columnName BETWEEN ${Long.MIN_VALUE} and ${Long.MAX_VALUE}))"
else -> "($columnName ${testTable.long.columnType} NOT NULL)"
}
assertTrue(testTable.ddl.single().endsWith(ddlEnding, ignoreCase = true))

testTable.insert { it[long] = Long.MIN_VALUE }
testTable.insert { it[long] = Long.MAX_VALUE }
assertEquals(2, testTable.select(testTable.long).count())

val tableName = testTable.nameInDatabaseCase()
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
val outOfRangeValue = Long.MIN_VALUE.toBigDecimal() - 1.toBigDecimal()
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
}
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
val outOfRangeValue = Long.MAX_VALUE.toBigDecimal() + 1.toBigDecimal()
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
}
}
}
}

0 comments on commit d2cf30f

Please sign in to comment.