Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

chore!: Change H2 Oracle longType and longAutoincType from NUMBER(19) to BIGINT and add CHECK constraint in Oracle and SQLite #2273

Open
wants to merge 2 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
23 changes: 23 additions & 0 deletions documentation-website/Writerside/topics/Breaking-Changes.md
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,29 @@
-- Starting from version 0.57.0
INSERT INTO TEST DEFAULT VALUES
```
* In H2 Oracle, the `long()` column now maps to data type `BIGINT` instead of `NUMBER(19)`.
In Oracle, using the long column in a table now also creates a CHECK constraint to ensure that no out-of-range values are inserted.
Exposed does not ensure this behaviour for SQLite. If you want to do that, please use the following CHECK constraint:

```kotlin
val long = long("long_column").check { column ->
fun typeOf(value: String) = object : ExpressionWithColumnType<String>() {
override fun toQueryBuilder(queryBuilder: QueryBuilder) = queryBuilder { append("typeof($value)") }
override val columnType: IColumnType<String> = TextColumnType()
}
Expression.build { typeOf(column.name) eq stringLiteral("integer") }
}

val long = long("long_column").nullable().check { column ->
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(column.name) eq stringLiteral("integer") }
column.isNull() or typeCondition
}
```

## 0.56.0
* If the `distinct` parameter of `groupConcat()` is set to `true`, when using Oracle or SQL Server, this will now fail early with an
Expand Down
13 changes: 12 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 @@ -753,7 +753,9 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
}

/** Creates a numeric column, with the specified [name], for storing 8-byte integers. */
fun long(name: String): Column<Long> = registerColumn(name, LongColumnType())
fun long(name: String): Column<Long> = registerColumn(name, LongColumnType()).apply {
check("${generatedSignedCheckPrefix}long_${this.unquotedName()}") { it.between(Long.MIN_VALUE, Long.MAX_VALUE) }
}

/** Creates a numeric column, with the specified [name], for storing 8-byte unsigned integers.
*
Expand Down Expand Up @@ -1698,6 +1700,7 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
append("IF NOT EXISTS ")
}
append(TransactionManager.current().identity(this@Table))

if (columns.isNotEmpty()) {
columns.joinTo(this, prefix = " (") { column ->
column.descriptionDdl(false)
Expand Down Expand Up @@ -1744,6 +1747,14 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
} else {
it
}
}.let {
if (currentDialect !is OracleDialect) {
it.filterNot { (name, _) ->
name.startsWith("${generatedSignedCheckPrefix}long")
}
} else {
it
}
}.ifEmpty { null }
filteredChecks?.mapIndexed { index, (name, op) ->
val resolvedName = name.ifBlank { "check_${tableName}_$index" }
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,11 @@ 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 ->
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
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 @@ -210,8 +210,11 @@ 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 ->
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
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 @@ -271,8 +271,11 @@ 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 ->
TestDB.SQLITE ->
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
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 @@ -320,7 +320,7 @@ class CreateTableTests : DatabaseTestsBase() {
fkName = fkName
)
}
withDb {
withDb { testDb ->
val t = TransactionManager.current()
val expected = listOfNotNull(
child.autoIncColumn?.autoIncColumnType?.sequence?.createStatement()?.single(),
Expand All @@ -329,6 +329,11 @@ class CreateTableTests : DatabaseTestsBase() {
" CONSTRAINT ${t.db.identifierManager.cutIfNecessaryAndQuote(fkName).inProperCase()}" +
" FOREIGN KEY (${t.identity(child.parentId)})" +
" REFERENCES ${t.identity(parent)}(${t.identity(parent.id)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_child1_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
)
assertEqualCollections(child.ddl, expected)
Expand All @@ -346,12 +351,17 @@ class CreateTableTests : DatabaseTestsBase() {
onDelete = ReferenceOption.NO_ACTION,
)
}
withDb {
withDb { testDb ->
val expected = "CREATE TABLE " + addIfNotExistsIfSupported() + "${this.identity(child)} (" +
"${child.columns.joinToString { it.descriptionDdl(false) }}," +
" CONSTRAINT ${"fk_Child_parent_id__id".inProperCase()}" +
" FOREIGN KEY (${this.identity(child.parentId)})" +
" REFERENCES ${this.identity(parent)}(${this.identity(parent.id)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_Child_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
assertEquals(child.ddl.last(), expected)
}
Expand All @@ -368,12 +378,17 @@ class CreateTableTests : DatabaseTestsBase() {
onDelete = ReferenceOption.NO_ACTION,
)
}
withDb {
withDb { testDb ->
val expected = "CREATE TABLE " + addIfNotExistsIfSupported() + "${this.identity(child)} (" +
"${child.columns.joinToString { it.descriptionDdl(false) }}," +
" CONSTRAINT ${"fk_Child2_parent_id__id".inProperCase()}" +
" FOREIGN KEY (${this.identity(child.parentId)})" +
" REFERENCES ${this.identity(parent)}(${this.identity(parent.id)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_Child2_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
assertEquals(child.ddl.last(), expected)
}
Expand All @@ -394,7 +409,7 @@ class CreateTableTests : DatabaseTestsBase() {
fkName = fkName
)
}
withDb {
withDb { testDb ->
val t = TransactionManager.current()
val expected = listOfNotNull(
child.autoIncColumn?.autoIncColumnType?.sequence?.createStatement()?.single(),
Expand All @@ -403,6 +418,11 @@ class CreateTableTests : DatabaseTestsBase() {
" CONSTRAINT ${t.db.identifierManager.cutIfNecessaryAndQuote(fkName).inProperCase()}" +
" FOREIGN KEY (${t.identity(child.parentId)})" +
" REFERENCES ${t.identity(parent)}(${t.identity(parent.uniqueId)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_child2_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
)
assertEqualCollections(child.ddl, expected)
Expand All @@ -422,7 +442,7 @@ class CreateTableTests : DatabaseTestsBase() {
fkName = fkName
)
}
withDb {
withDb { testDb ->
val t = TransactionManager.current()
val expected = listOfNotNull(
child.autoIncColumn?.autoIncColumnType?.sequence?.createStatement()?.single(),
Expand All @@ -431,6 +451,11 @@ class CreateTableTests : DatabaseTestsBase() {
" CONSTRAINT ${t.db.identifierManager.cutIfNecessaryAndQuote(fkName).inProperCase()}" +
" FOREIGN KEY (${t.identity(child.parentId)})" +
" REFERENCES ${t.identity(parent)}(${t.identity(parent.id)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_child3_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
)
assertEqualCollections(child.ddl, expected)
Expand All @@ -453,7 +478,7 @@ class CreateTableTests : DatabaseTestsBase() {
fkName = fkName
)
}
withDb {
withDb { testDb ->
val t = TransactionManager.current()
val expected = listOfNotNull(
child.autoIncColumn?.autoIncColumnType?.sequence?.createStatement()?.single(),
Expand All @@ -462,6 +487,11 @@ class CreateTableTests : DatabaseTestsBase() {
" CONSTRAINT ${t.db.identifierManager.cutIfNecessaryAndQuote(fkName).inProperCase()}" +
" FOREIGN KEY (${t.identity(child.parentId)})" +
" REFERENCES ${t.identity(parent)}(${t.identity(parent.uniqueId)})" +
if (testDb == TestDB.ORACLE) {
", CONSTRAINT chk_child4_signed_long_id CHECK (${this.identity(parent.id)} BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"
} else {
""
} +
")"
)
assertEqualCollections(child.ddl, expected)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -108,6 +108,40 @@ 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.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())

// SQLite is excluded because it is not possible to enforce the range without a special CHECK constraint
// that the user can implement if they want to
if (testDb != TestDB.SQLITE) {
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)")
}
}
}
}

@Test
fun testParams() {
val testTable = object : Table("test_table") {
Expand Down
Loading