Skip to content

Commit bc28075

Browse files
committed
chore: Exclude SQLite from out-of-range check since the raw SQL behaviour is that it is not possible to enforce the range without a special CHECK constraint that checks the type
1 parent d27a577 commit bc28075

File tree

6 files changed

+50
-52
lines changed

6 files changed

+50
-52
lines changed

documentation-website/Writerside/topics/Breaking-Changes.md

Lines changed: 23 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -24,6 +24,29 @@
2424
-- Starting from version 0.57.0
2525
INSERT INTO TEST DEFAULT VALUES
2626
```
27+
* In H2 Oracle, the `long()` column now maps to data type `BIGINT` instead of `NUMBER(19)`.
28+
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.
29+
Exposed does not ensure this behaviour for SQLite. If you want to do that, please use the following CHECK constraint:
30+
31+
```kotlin
32+
val long = long("long_column").check { column ->
33+
fun typeOf(value: String) = object : ExpressionWithColumnType<String>() {
34+
override fun toQueryBuilder(queryBuilder: QueryBuilder) = queryBuilder { append("typeof($value)") }
35+
override val columnType: IColumnType<String> = TextColumnType()
36+
}
37+
Expression.build { typeOf(column.name) eq stringLiteral("integer") }
38+
}
39+
40+
val long = long("long_column").nullable().check { column ->
41+
fun typeOf(value: String) = object : ExpressionWithColumnType<String>() {
42+
override fun toQueryBuilder(queryBuilder: QueryBuilder) = queryBuilder { append("typeof($value)") }
43+
override val columnType: IColumnType<String> = TextColumnType()
44+
}
45+
46+
val typeCondition = Expression.build { typeOf(column.name) eq stringLiteral("integer") }
47+
column.isNull() or typeCondition
48+
}
49+
```
2750

2851
## 0.56.0
2952
* If the `distinct` parameter of `groupConcat()` is set to `true`, when using Oracle or SQL Server, this will now fail early with an
@@ -44,8 +67,6 @@
4467
that is also type restricted to `Comparable` (for example, `avg()`) will also require defining a new function. In this event, please
4568
also leave a comment on [YouTrack](https://youtrack.jetbrains.com/issue/EXPOSED-577) with a use case so the original function signature
4669
can be potentially reassessed.
47-
* In H2 Oracle, the `long()` column now maps to data type `BIGINT` instead of `NUMBER(19)`.
48-
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.
4970

5071
## 0.55.0
5172
* The `DeleteStatement` property `table` is now deprecated in favor of `targetsSet`, which holds a `ColumnSet` that may be a `Table` or `Join`.

exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/Table.kt

Lines changed: 12 additions & 35 deletions
Original file line numberDiff line numberDiff line change
@@ -753,7 +753,9 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
753753
}
754754

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

758760
/** Creates a numeric column, with the specified [name], for storing 8-byte unsigned integers.
759761
*
@@ -1699,10 +1701,6 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
16991701
}
17001702
append(TransactionManager.current().identity(this@Table))
17011703

1702-
// Add CHECK constraint to Long columns in Oracle and SQLite.
1703-
// It is done here because special handling is necessary based on the dialect.
1704-
addLongColumnCheckConstraintIfNeeded()
1705-
17061704
if (columns.isNotEmpty()) {
17071705
columns.joinTo(this, prefix = " (") { column ->
17081706
column.descriptionDdl(false)
@@ -1744,8 +1742,15 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
17441742
}.let {
17451743
if (currentDialect !is SQLiteDialect && currentDialect !is OracleDialect) {
17461744
it.filterNot { (name, _) ->
1747-
name.startsWith("${generatedSignedCheckPrefix}integer") ||
1748-
name.startsWith("${generatedSignedCheckPrefix}long")
1745+
name.startsWith("${generatedSignedCheckPrefix}integer")
1746+
}
1747+
} else {
1748+
it
1749+
}
1750+
}.let {
1751+
if (currentDialect !is OracleDialect) {
1752+
it.filterNot { (name, _) ->
1753+
name.startsWith("${generatedSignedCheckPrefix}long")
17491754
}
17501755
} else {
17511756
it
@@ -1770,34 +1775,6 @@ open class Table(name: String = "") : ColumnSet(), DdlAware {
17701775
return createAutoIncColumnSequence() + createTable + createConstraint
17711776
}
17721777

1773-
private fun addLongColumnCheckConstraintIfNeeded() {
1774-
if (currentDialect is OracleDialect || currentDialect is SQLiteDialect) {
1775-
columns.filter { it.columnType is LongColumnType }.forEach { column ->
1776-
val name = column.name
1777-
val checkName = "${generatedSignedCheckPrefix}long_$name"
1778-
if (checkConstraints.none { it.first == checkName }) {
1779-
column.check(checkName) {
1780-
if (currentDialect is SQLiteDialect) {
1781-
fun typeOf(value: String) = object : ExpressionWithColumnType<String>() {
1782-
override fun toQueryBuilder(queryBuilder: QueryBuilder) = queryBuilder { append("typeof($value)") }
1783-
override val columnType: IColumnType<String> = TextColumnType()
1784-
}
1785-
1786-
val typeCondition = Expression.build { typeOf(name) eq stringLiteral("integer") }
1787-
if (column.columnType.nullable) {
1788-
column.isNull() or typeCondition
1789-
} else {
1790-
typeCondition
1791-
}
1792-
} else {
1793-
it.between(Long.MIN_VALUE, Long.MAX_VALUE)
1794-
}
1795-
}
1796-
}
1797-
}
1798-
}
1799-
}
1800-
18011778
private fun createAutoIncColumnSequence(): List<String> {
18021779
return autoIncColumn?.autoIncColumnType?.sequence?.createStatement().orEmpty()
18031780
}

exposed-java-time/src/test/kotlin/org/jetbrains/exposed/DefaultsTest.kt

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -274,8 +274,7 @@ class DefaultsTest : DatabaseTestsBase() {
274274
"${"t10".inProperCase()} $timeType${testTable.t10.constraintNamePart()} ${tLiteral.itOrNull()}" +
275275
when (testDb) {
276276
TestDB.SQLITE ->
277-
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
278-
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
277+
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
279278
TestDB.ORACLE ->
280279
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
281280
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"

exposed-jodatime/src/test/kotlin/org/jetbrains/exposed/JodaTimeDefaultsTest.kt

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -211,8 +211,7 @@ class JodaTimeDefaultsTest : DatabaseTestsBase() {
211211
"${"t6".inProperCase()} $timeType${testTable.t6.constraintNamePart()} ${tLiteral.itOrNull()}" +
212212
when (testDb) {
213213
TestDB.SQLITE ->
214-
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
215-
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
214+
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
216215
TestDB.ORACLE ->
217216
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
218217
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"

exposed-kotlin-datetime/src/test/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/DefaultsTest.kt

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -272,8 +272,7 @@ class DefaultsTest : DatabaseTestsBase() {
272272
"${"t10".inProperCase()} $timeType${testTable.t10.constraintNamePart()} ${tLiteral.itOrNull()}" +
273273
when (testDb) {
274274
TestDB.SQLITE ->
275-
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
276-
", CONSTRAINT chk_t_signed_long_l CHECK (typeof(l) = 'integer')"
275+
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})"
277276
TestDB.ORACLE ->
278277
", CONSTRAINT chk_t_signed_integer_id CHECK (${"id".inProperCase()} BETWEEN ${Int.MIN_VALUE} AND ${Int.MAX_VALUE})" +
279278
", CONSTRAINT chk_t_signed_long_l CHECK (L BETWEEN ${Long.MIN_VALUE} AND ${Long.MAX_VALUE})"

exposed-tests/src/test/kotlin/org/jetbrains/exposed/sql/tests/shared/types/NumericColumnTypesTests.kt

Lines changed: 12 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -117,7 +117,6 @@ class NumericColumnTypesTests : DatabaseTestsBase() {
117117
withTables(testTable) { testDb ->
118118
val columnName = testTable.long.nameInDatabaseCase()
119119
val ddlEnding = when (testDb) {
120-
TestDB.SQLITE -> "CHECK (typeof($columnName) = 'integer'))"
121120
TestDB.ORACLE -> "CHECK ($columnName BETWEEN ${Long.MIN_VALUE} and ${Long.MAX_VALUE}))"
122121
else -> "($columnName ${testTable.long.columnType} NOT NULL)"
123122
}
@@ -127,14 +126,18 @@ class NumericColumnTypesTests : DatabaseTestsBase() {
127126
testTable.insert { it[long] = Long.MAX_VALUE }
128127
assertEquals(2, testTable.select(testTable.long).count())
129128

130-
val tableName = testTable.nameInDatabaseCase()
131-
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
132-
val outOfRangeValue = Long.MIN_VALUE.toBigDecimal() - 1.toBigDecimal()
133-
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
134-
}
135-
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
136-
val outOfRangeValue = Long.MAX_VALUE.toBigDecimal() + 1.toBigDecimal()
137-
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
129+
// SQLite is excluded because it is not possible to enforce the range without a special CHECK constraint
130+
// that the user can implement if they want to
131+
if (testDb != TestDB.SQLITE) {
132+
val tableName = testTable.nameInDatabaseCase()
133+
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
134+
val outOfRangeValue = Long.MIN_VALUE.toBigDecimal() - 1.toBigDecimal()
135+
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
136+
}
137+
assertFailAndRollback(message = "Out-of-range error (or CHECK constraint violation for SQLite & Oracle)") {
138+
val outOfRangeValue = Long.MAX_VALUE.toBigDecimal() + 1.toBigDecimal()
139+
exec("INSERT INTO $tableName ($columnName) VALUES ($outOfRangeValue)")
140+
}
138141
}
139142
}
140143
}

0 commit comments

Comments
 (0)