Skip to content

Commit

Permalink
fix: EXPOSED-353 dateLiteral does not work on OracleDB 12c or 19c (#2057
Browse files Browse the repository at this point in the history
)

* EXPOSED-353 dateLiteral does not work on OracleDB 12c or 19c #1338
  • Loading branch information
obabichevjb committed May 3, 2024
1 parent 16140aa commit 048b62a
Show file tree
Hide file tree
Showing 7 changed files with 311 additions and 28 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -66,12 +66,6 @@ internal object OracleDataTypeProvider : DataTypeProvider() {

override fun jsonType(): String = "VARCHAR2(4000)"

override fun processForDefaultValue(e: Expression<*>): String = when {
e is LiteralOp<*> && (e.columnType as? IDateColumnType)?.hasTimePart == false -> "DATE ${super.processForDefaultValue(e)}"
e is LiteralOp<*> && e.columnType is IDateColumnType -> "TIMESTAMP ${super.processForDefaultValue(e)}"
else -> super.processForDefaultValue(e)
}

override fun hexToDb(hexString: String): String = "HEXTORAW('$hexString')"
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -111,6 +111,15 @@ private fun dateTimeWithFractionFormat(fraction: Int): DateTimeFormatter {
return DateTimeFormatter.ofPattern(newFormat).withLocale(Locale.ROOT).withZone(ZoneId.systemDefault())
}

private fun oracleDateTimeLiteral(instant: Instant) =
"TO_TIMESTAMP('${SQLITE_AND_ORACLE_DATE_TIME_STRING_FORMATTER.format(instant)}', 'YYYY-MM-DD HH24:MI:SS.FF3')"

private fun oracleDateTimeWithTimezoneLiteral(dateTime: OffsetDateTime) =
"TO_TIMESTAMP_TZ('${dateTime.format(ORACLE_OFFSET_DATE_TIME_FORMATTER)}', 'YYYY-MM-DD HH24:MI:SS.FF6 TZH:TZM')"

private fun oracleDateLiteral(instant: Instant) =
"TO_DATE('${DEFAULT_DATE_STRING_FORMATTER.format(instant)}', 'YYYY-MM-DD')"

@Suppress("MagicNumber")
private val LocalDate.millis get() = atStartOfDay(ZoneId.systemDefault()).toEpochSecond() * 1000

Expand All @@ -127,7 +136,14 @@ class JavaLocalDateColumnType : ColumnType<LocalDate>(), IDateColumnType {

override fun nonNullValueToString(value: LocalDate): String {
val instant = Instant.from(value.atStartOfDay(ZoneId.systemDefault()))
return "'${DEFAULT_DATE_STRING_FORMATTER.format(instant)}'"
val formatted = DEFAULT_DATE_STRING_FORMATTER.format(instant)
if (currentDialect is OracleDialect) {
// Date literal in Oracle DB must match NLS_DATE_FORMAT parameter.
// That parameter can be changed on DB level.
// But format can be also specified per literal with TO_DATE function
return oracleDateLiteral(instant)
}
return "'$formatted'"
}

override fun valueFromDB(value: Any): LocalDate? = when (value) {
Expand Down Expand Up @@ -173,7 +189,7 @@ class JavaLocalDateTimeColumnType : ColumnType<LocalDateTime>(), IDateColumnType
val dialect = currentDialect
return when {
dialect is SQLiteDialect -> "'${SQLITE_AND_ORACLE_DATE_TIME_STRING_FORMATTER.format(instant)}'"
dialect is OracleDialect || dialect.h2Mode == H2Dialect.H2CompatibilityMode.Oracle -> "'${SQLITE_AND_ORACLE_DATE_TIME_STRING_FORMATTER.format(instant)}'"
dialect is OracleDialect -> oracleDateTimeLiteral(instant)
dialect is MysqlDialect -> {
val formatter = if (dialect.isFractionDateTimeSupported()) MYSQL_FRACTION_DATE_TIME_STRING_FORMATTER else MYSQL_DATE_TIME_STRING_FORMATTER
"'${formatter.format(instant)}'"
Expand Down Expand Up @@ -242,12 +258,10 @@ class JavaLocalTimeColumnType : ColumnType<LocalTime>(), IDateColumnType {

override fun nonNullValueToString(value: LocalTime): String {
val dialect = currentDialect
val formatter = if (dialect is OracleDialect || dialect.h2Mode == H2Dialect.H2CompatibilityMode.Oracle) {
ORACLE_TIME_STRING_FORMATTER
} else {
DEFAULT_TIME_STRING_FORMATTER
if (dialect is OracleDialect || dialect.h2Mode == H2Dialect.H2CompatibilityMode.Oracle) {
return "TIMESTAMP '${ORACLE_TIME_STRING_FORMATTER.format(value)}'"
}
return "'${formatter.format(value)}'"
return "'${DEFAULT_TIME_STRING_FORMATTER.format(value)}'"
}

override fun valueFromDB(value: Any): LocalTime = when (value) {
Expand Down Expand Up @@ -295,8 +309,11 @@ class JavaInstantColumnType : ColumnType<Instant>(), IDateColumnType {
override fun nonNullValueToString(value: Instant): String {
val dialect = currentDialect
return when {
dialect is OracleDialect || dialect.h2Mode == H2Dialect.H2CompatibilityMode.Oracle ->
dialect is OracleDialect -> oracleDateTimeLiteral(value)

dialect is SQLiteDialect ->
"'${SQLITE_AND_ORACLE_DATE_TIME_STRING_FORMATTER.format(value)}'"

dialect is MysqlDialect -> {
val formatter = if (dialect.isFractionDateTimeSupported()) MYSQL_FRACTION_DATE_TIME_STRING_FORMATTER else MYSQL_DATE_TIME_STRING_FORMATTER
"'${formatter.format(value)}'"
Expand Down Expand Up @@ -350,7 +367,7 @@ class JavaOffsetDateTimeColumnType : ColumnType<OffsetDateTime>(), IDateColumnTy
override fun nonNullValueToString(value: OffsetDateTime): String = when (currentDialect) {
is SQLiteDialect -> "'${value.format(SQLITE_OFFSET_DATE_TIME_FORMATTER)}'"
is MysqlDialect -> "'${value.format(MYSQL_OFFSET_DATE_TIME_FORMATTER)}'"
is OracleDialect -> "'${value.format(ORACLE_OFFSET_DATE_TIME_FORMATTER)}'"
is OracleDialect -> oracleDateTimeWithTimezoneLiteral(value)
else -> "'${value.format(DEFAULT_OFFSET_DATE_TIME_FORMATTER)}'"
}

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,93 @@
package org.jetbrains.exposed

import org.jetbrains.exposed.dao.id.IntIdTable
import org.jetbrains.exposed.sql.insert
import org.jetbrains.exposed.sql.javatime.*
import org.jetbrains.exposed.sql.selectAll
import org.jetbrains.exposed.sql.tests.DatabaseTestsBase
import org.jetbrains.exposed.sql.tests.shared.assertEquals
import org.junit.Test
import java.time.Instant
import java.time.LocalDate
import java.time.LocalDateTime
import kotlin.test.assertNotNull

class DateTimeLiteralTest : DatabaseTestsBase() {
private val defaultDate = LocalDate.of(2000, 1, 1)
private val futureDate = LocalDate.of(3000, 1, 1)

object TableWithDate : IntIdTable() {
val date = date("date")
}

private val defaultDatetime = LocalDateTime.of(2000, 1, 1, 8, 0, 0, 100000000)
private val futureDatetime = LocalDateTime.of(3000, 1, 1, 8, 0, 0, 100000000)

object TableWithDatetime : IntIdTable() {
val datetime = datetime("datetime")
}

private val defaultTimestamp = Instant.parse("2000-01-01T01:00:00.00Z")

object TableWithTimestamp : IntIdTable() {
val timestamp = timestamp("timestamp")
}

@Test
fun testSelectByDateLiteralEquality() {
withTables(TableWithDate) {
TableWithDate.insert {
it[date] = defaultDate
}

val query = TableWithDate.select(TableWithDate.date).where { TableWithDate.date eq dateLiteral(defaultDate) }
assertEquals(defaultDate, query.single()[TableWithDate.date])
}
}

@Test
fun testSelectByDateLiteralComparison() {
withTables(TableWithDate) {
TableWithDate.insert {
it[date] = defaultDate
}
val query = TableWithDate.selectAll().where { TableWithDate.date less dateLiteral(futureDate) }
assertNotNull(query.firstOrNull())
}
}

@Test
fun testSelectByDatetimeLiteralEquality() {
withTables(TableWithDatetime) {
TableWithDatetime.insert {
it[datetime] = defaultDatetime
}

val query = TableWithDatetime.select(TableWithDatetime.datetime).where { TableWithDatetime.datetime eq dateTimeLiteral(defaultDatetime) }
assertEquals(defaultDatetime, query.single()[TableWithDatetime.datetime])
}
}

@Test
fun testSelectByDatetimeLiteralComparison() {
withTables(TableWithDatetime) {
TableWithDatetime.insert {
it[datetime] = defaultDatetime
}
val query = TableWithDatetime.selectAll().where { TableWithDatetime.datetime less dateTimeLiteral(futureDatetime) }
assertNotNull(query.firstOrNull())
}
}

@Test
fun testSelectByTimestampLiteralEquality() {
withTables(TableWithTimestamp) {
TableWithTimestamp.insert {
it[timestamp] = defaultTimestamp
}

val query = TableWithTimestamp.select(TableWithTimestamp.timestamp).where { TableWithTimestamp.timestamp eq timestampLiteral(defaultTimestamp) }
assertEquals(defaultTimestamp, query.single()[TableWithTimestamp.timestamp])
}
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,15 @@ private fun dateTimeWithFractionFormat(fraction: Int): DateTimeFormatter {
return DateTimeFormat.forPattern(newFormat)
}

private fun oracleDateTimeLiteral(dateTime: DateTime) =
"TO_TIMESTAMP('${DEFAULT_DATE_TIME_STRING_FORMATTER.print(dateTime)}', 'YYYY-MM-DD HH24:MI:SS.FF3')"

private fun oracleDateTimeWithTimezoneLiteral(dateTime: DateTime) =
"TO_TIMESTAMP_TZ('${ORACLE_DATE_TIME_WITH_TIME_ZONE_FORMATTER.print(dateTime)}', 'YYYY-MM-DD HH24:MI:SS.FF3 TZH:TZM')"

private fun oracleDateLiteral(dateTime: DateTime) =
"TO_DATE('${DEFAULT_DATE_STRING_FORMATTER.print(dateTime)}', 'YYYY-MM-DD')"

/**
* Column for storing dates, as [DateTime]. If [time] is set to `true`, both date and time data is stored.
*
Expand All @@ -66,12 +75,16 @@ class DateColumnType(val time: Boolean) : ColumnType<DateTime>(), IDateColumnTyp
override fun nonNullValueToString(value: DateTime): String {
return if (time) {
when {
currentDialect is OracleDialect -> oracleDateTimeLiteral(value.toDateTime(DateTimeZone.getDefault()))
(currentDialect as? MysqlDialect)?.isFractionDateTimeSupported() == false ->
"'${MYSQL_DATE_TIME_STRING_FORMATTER.print(value.toDateTime(DateTimeZone.getDefault()))}'"
else -> "'${DEFAULT_DATE_TIME_STRING_FORMATTER.print(value.toDateTime(DateTimeZone.getDefault()))}'"
}
} else {
"'${DEFAULT_DATE_STRING_FORMATTER.print(value)}'"
if (currentDialect is OracleDialect) {
return oracleDateLiteral(value)
}
return "'${DEFAULT_DATE_STRING_FORMATTER.print(value)}'"
}
}

Expand Down Expand Up @@ -168,7 +181,7 @@ class DateTimeWithTimeZoneColumnType : ColumnType<DateTime>(), IDateColumnType {
override fun nonNullValueToString(value: DateTime): String = when (currentDialect) {
is SQLiteDialect -> "'${SQLITE_AND_MYSQL_DATE_TIME_WITH_TIME_ZONE_FORMATTER.print(value)}'"
is MysqlDialect -> "'${SQLITE_AND_MYSQL_DATE_TIME_WITH_TIME_ZONE_FORMATTER.print(value)}'"
is OracleDialect -> "'${ORACLE_DATE_TIME_WITH_TIME_ZONE_FORMATTER.print(value)}'"
is OracleDialect -> oracleDateTimeWithTimezoneLiteral(value.toDateTime(DateTimeZone.getDefault()))
else -> "'${DEFAULT_DATE_TIME_WITH_TIME_ZONE_FORMATTER.print(value)}'"
}

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
package org.jetbrains.exposed

import org.jetbrains.exposed.dao.id.IntIdTable
import org.jetbrains.exposed.sql.insert
import org.jetbrains.exposed.sql.jodatime.dateTimeLiteral
import org.jetbrains.exposed.sql.jodatime.datetime
import org.jetbrains.exposed.sql.selectAll
import org.jetbrains.exposed.sql.tests.DatabaseTestsBase
import org.jetbrains.exposed.sql.tests.shared.assertEquals
import org.joda.time.DateTime
import org.joda.time.format.DateTimeFormat
import org.junit.Test
import kotlin.test.assertNotNull

class JodaDateTimeLiteralTest : DatabaseTestsBase() {
private val pattern = "dd-mm-yyyy hh.mm.ss"

private val defaultDatetime: DateTime = DateTime.parse("01-01-2000 01.00.00", DateTimeFormat.forPattern(pattern))
private val futureDatetime: DateTime = DateTime.parse("01-01-3000 01.00.00", DateTimeFormat.forPattern(pattern))

object TableWithDatetime : IntIdTable() {
val datetime = datetime("datetime")
}

@Test
fun testSelectByDatetimeLiteralEquality() {
withTables(TableWithDatetime) {
TableWithDatetime.insert {
it[datetime] = defaultDatetime
}

val query = TableWithDatetime.select(TableWithDatetime.datetime).where { TableWithDatetime.datetime eq dateTimeLiteral(defaultDatetime) }
assertEquals(defaultDatetime, query.single()[TableWithDatetime.datetime])
}
}

@Test
fun testSelectByDatetimeLiteralComparison() {
withTables(TableWithDatetime) {
TableWithDatetime.insert {
it[datetime] = defaultDatetime
}
val query = TableWithDatetime.selectAll().where { TableWithDatetime.datetime less dateTimeLiteral(futureDatetime) }
assertNotNull(query.firstOrNull())
}
}
}
Loading

0 comments on commit 048b62a

Please sign in to comment.