From 6b0873adb3dbb7f3233c64633b75449d78f63440 Mon Sep 17 00:00:00 2001 From: Jocelyne Date: Fri, 7 Jul 2023 20:00:40 +0100 Subject: [PATCH] feat: Add support for timestamp with time zone --- exposed-core/api/exposed-core.api | 2 + .../jetbrains/exposed/sql/vendors/Default.kt | 3 + .../org/jetbrains/exposed/sql/vendors/H2.kt | 2 + .../jetbrains/exposed/sql/vendors/Mysql.kt | 16 ++- .../exposed/sql/vendors/SQLServerDialect.kt | 6 + .../exposed/sql/vendors/SQLiteDialect.kt | 1 + exposed-java-time/api/exposed-java-time.api | 16 +++ .../sql/javatime/JavaDateColumnType.kt | 77 +++++++++++++ .../org/jetbrains/exposed/JavaTimeTests.kt | 105 +++++++++++++++++- .../api/exposed-kotlin-datetime.api | 16 +++ .../kotlin/datetime/KotlinDateColumnType.kt | 78 +++++++++++++ .../sql/kotlin/datetime/KotlinTimeTests.kt | 100 ++++++++++++++++- 12 files changed, 416 insertions(+), 6 deletions(-) diff --git a/exposed-core/api/exposed-core.api b/exposed-core/api/exposed-core.api index 0c4bb65451..04af20c46a 100644 --- a/exposed-core/api/exposed-core.api +++ b/exposed-core/api/exposed-core.api @@ -3246,6 +3246,7 @@ public abstract class org/jetbrains/exposed/sql/vendors/DataTypeProvider { public fun shortType ()Ljava/lang/String; public fun textType ()Ljava/lang/String; public fun timeType ()Ljava/lang/String; + public fun timestampWithTimeZoneType ()Ljava/lang/String; public fun ubyteType ()Ljava/lang/String; public fun uintegerType ()Ljava/lang/String; public fun ulongType ()Ljava/lang/String; @@ -3552,6 +3553,7 @@ public class org/jetbrains/exposed/sql/vendors/MysqlDialect : org/jetbrains/expo public fun getSupportsTernaryAffectedRowValues ()Z public fun isAllowedAsColumnDefault (Lorg/jetbrains/exposed/sql/Expression;)Z public final fun isFractionDateTimeSupported ()Z + public final fun isTimeZoneOffsetSupported ()Z public fun setSchema (Lorg/jetbrains/exposed/sql/Schema;)Ljava/lang/String; } diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Default.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Default.kt index a76742f5cd..4267313334 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Default.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Default.kt @@ -90,6 +90,9 @@ abstract class DataTypeProvider { /** Data type for storing both date and time without a time zone. */ open fun dateTimeType(): String = "DATETIME" + /** Data type for storing both date and time with a time zone. */ + open fun timestampWithTimeZoneType(): String = "TIMESTAMP WITH TIME ZONE" + /** Time type for storing time without a time zone. */ open fun timeType(): String = "TIME" diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt index 6e959d4b60..b26c613c3e 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/H2.kt @@ -14,6 +14,8 @@ internal object H2DataTypeProvider : DataTypeProvider() { override fun uuidType(): String = "UUID" override fun dateTimeType(): String = "DATETIME(9)" + override fun timestampWithTimeZoneType(): String = "TIMESTAMP(9) WITH TIME ZONE" + override fun jsonBType(): String = "JSON" override fun hexToDb(hexString: String): String = "X'$hexString'" diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Mysql.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Mysql.kt index 5a1f6dd6f5..51b939bb31 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Mysql.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/Mysql.kt @@ -15,6 +15,15 @@ internal object MysqlDataTypeProvider : DataTypeProvider() { override fun dateTimeType(): String = if ((currentDialect as? MysqlDialect)?.isFractionDateTimeSupported() == true) "DATETIME(6)" else "DATETIME" + override fun timestampWithTimeZoneType(): String = + if ((currentDialect as? MysqlDialect)?.isTimeZoneOffsetSupported() == true) { + "TIMESTAMP(6)" + } else { + throw UnsupportedByDialectException( + "This vendor does not support timestamp with time zone data type for this version", currentDialect + ) + } + override fun ubyteType(): String = "TINYINT UNSIGNED" override fun ushortType(): String = "SMALLINT UNSIGNED" @@ -249,7 +258,9 @@ internal open class MysqlFunctionProvider : FunctionProvider() { open class MysqlDialect : VendorDialect(dialectName, MysqlDataTypeProvider, MysqlFunctionProvider.INSTANCE) { internal val isMysql8: Boolean by lazy { - TransactionManager.current().db.isVersionCovers(BigDecimal("8.0")) + TransactionManager.current().db.also { + println("MySQL version = ${it.version}") + }.isVersionCovers(BigDecimal("8.0")) } override val supportsCreateSequence: Boolean = false @@ -262,6 +273,9 @@ open class MysqlDialect : VendorDialect(dialectName, MysqlDataTypeProvider, Mysq fun isFractionDateTimeSupported(): Boolean = TransactionManager.current().db.isVersionCovers(BigDecimal("5.6")) + // Available from MySQL 8.0.19 + fun isTimeZoneOffsetSupported(): Boolean = (currentDialect !is MariaDBDialect) && isMysql8 + override fun isAllowedAsColumnDefault(e: Expression<*>): Boolean { if (super.isAllowedAsColumnDefault(e)) return true val acceptableDefaults = arrayOf("CURRENT_TIMESTAMP", "CURRENT_TIMESTAMP()", "NOW()", "CURRENT_TIMESTAMP(6)", "NOW(6)") 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 2c86b3dbdf..11ea084bbf 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 @@ -17,6 +17,12 @@ internal object SQLServerDataTypeProvider : DataTypeProvider() { override fun uuidType(): String = "uniqueidentifier" override fun uuidToDB(value: UUID): Any = value.toString() override fun dateTimeType(): String = "DATETIME2" + override fun timestampWithTimeZoneType(): String = + if ((currentDialect as? H2Dialect)?.h2Mode == H2Dialect.H2CompatibilityMode.SQLServer) { + "TIMESTAMP(9) WITH TIME ZONE" + } else { + "DATETIMEOFFSET" + } override fun booleanType(): String = "BIT" override fun booleanToStatementString(bool: Boolean): String = if (bool) "1" else "0" diff --git a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt index 5193dd0391..cc6f9926d0 100644 --- a/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt +++ b/exposed-core/src/main/kotlin/org/jetbrains/exposed/sql/vendors/SQLiteDialect.kt @@ -15,6 +15,7 @@ internal object SQLiteDataTypeProvider : DataTypeProvider() { override fun floatType(): String = "SINGLE" override fun binaryType(): String = "BLOB" override fun dateTimeType(): String = "TEXT" + override fun timestampWithTimeZoneType(): String = "TEXT" override fun dateType(): String = "TEXT" override fun booleanToStatementString(bool: Boolean) = if (bool) "1" else "0" override fun jsonType(): String = "TEXT" diff --git a/exposed-java-time/api/exposed-java-time.api b/exposed-java-time/api/exposed-java-time.api index 3e6f0f1101..c5f5b7240d 100644 --- a/exposed-java-time/api/exposed-java-time.api +++ b/exposed-java-time/api/exposed-java-time.api @@ -38,6 +38,7 @@ public final class org/jetbrains/exposed/sql/javatime/JavaDateColumnTypeKt { public static final fun duration (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; public static final fun time (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; public static final fun timestamp (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; + public static final fun timestampWithTimeZone (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; } public final class org/jetbrains/exposed/sql/javatime/JavaDateFunctionsKt { @@ -134,6 +135,21 @@ public final class org/jetbrains/exposed/sql/javatime/JavaLocalTimeColumnType : public final class org/jetbrains/exposed/sql/javatime/JavaLocalTimeColumnType$Companion { } +public final class org/jetbrains/exposed/sql/javatime/JavaOffsetDateTimeColumnType : org/jetbrains/exposed/sql/ColumnType, org/jetbrains/exposed/sql/IDateColumnType { + public static final field Companion Lorg/jetbrains/exposed/sql/javatime/JavaOffsetDateTimeColumnType$Companion; + public fun ()V + public fun getHasTimePart ()Z + public fun nonNullValueToString (Ljava/lang/Object;)Ljava/lang/String; + public fun notNullValueToDB (Ljava/lang/Object;)Ljava/lang/Object; + public fun readObject (Ljava/sql/ResultSet;I)Ljava/lang/Object; + public fun sqlType ()Ljava/lang/String; + public synthetic fun valueFromDB (Ljava/lang/Object;)Ljava/lang/Object; + public fun valueFromDB (Ljava/lang/Object;)Ljava/time/OffsetDateTime; +} + +public final class org/jetbrains/exposed/sql/javatime/JavaOffsetDateTimeColumnType$Companion { +} + public final class org/jetbrains/exposed/sql/javatime/Minute : org/jetbrains/exposed/sql/Function { public fun (Lorg/jetbrains/exposed/sql/Expression;)V public final fun getExpr ()Lorg/jetbrains/exposed/sql/Expression; diff --git a/exposed-java-time/src/main/kotlin/org/jetbrains/exposed/sql/javatime/JavaDateColumnType.kt b/exposed-java-time/src/main/kotlin/org/jetbrains/exposed/sql/javatime/JavaDateColumnType.kt index dfea6d7fec..ef2f68da85 100644 --- a/exposed-java-time/src/main/kotlin/org/jetbrains/exposed/sql/javatime/JavaDateColumnType.kt +++ b/exposed-java-time/src/main/kotlin/org/jetbrains/exposed/sql/javatime/JavaDateColumnType.kt @@ -5,6 +5,7 @@ import org.jetbrains.exposed.sql.ColumnType import org.jetbrains.exposed.sql.IDateColumnType import org.jetbrains.exposed.sql.Table import org.jetbrains.exposed.sql.vendors.H2Dialect +import org.jetbrains.exposed.sql.vendors.MysqlDialect import org.jetbrains.exposed.sql.vendors.OracleDialect import org.jetbrains.exposed.sql.vendors.SQLiteDialect import org.jetbrains.exposed.sql.vendors.currentDialect @@ -38,6 +39,25 @@ internal val DEFAULT_TIME_STRING_FORMATTER by lazy { DateTimeFormatter.ISO_LOCAL_TIME.withLocale(Locale.ROOT).withZone(ZoneId.systemDefault()) } +// Example result: 2023-07-07 14:42:29.343+02:00 or 2023-07-07 12:42:29.343Z +internal val SQLITE_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ofPattern( + "yyyy-MM-dd HH:mm:ss.SSS[XXX]", + Locale.ROOT + ) +} + +internal val MYSQL_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ofPattern( + "yyyy-MM-dd HH:mm:ss.SSSSSS[XXX]", + Locale.ROOT + ) +} + +internal val DEFAULT_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ISO_OFFSET_DATE_TIME.withLocale(Locale.ROOT) +} + internal fun formatterForDateString(date: String) = dateTimeWithFractionFormat(date.substringAfterLast('.', "").length) internal fun dateTimeWithFractionFormat(fraction: Int): DateTimeFormatter { val baseFormat = "yyyy-MM-d HH:mm:ss" @@ -238,6 +258,55 @@ class JavaInstantColumnType : ColumnType(), IDateColumnType { } } +class JavaOffsetDateTimeColumnType : ColumnType(), IDateColumnType { + override val hasTimePart: Boolean = true + + override fun sqlType(): String = currentDialect.dataTypeProvider.timestampWithTimeZoneType() + + override fun nonNullValueToString(value: Any): String = when (value) { + is OffsetDateTime -> { + when (currentDialect) { + is SQLiteDialect -> "'${value.format(SQLITE_OFFSET_DATE_TIME_FORMATTER)}'" + is MysqlDialect -> "'${value.format(MYSQL_OFFSET_DATE_TIME_FORMATTER)}'" + else -> "'${value.format(DEFAULT_OFFSET_DATE_TIME_FORMATTER)}'" + } + } + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + override fun valueFromDB(value: Any): OffsetDateTime = when (value) { + is OffsetDateTime -> value + is String -> OffsetDateTime.parse( + value, + if (currentDialect is MysqlDialect) MYSQL_OFFSET_DATE_TIME_FORMATTER else SQLITE_OFFSET_DATE_TIME_FORMATTER + ) + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + override fun readObject(rs: ResultSet, index: Int): Any? { + val offsetDateTime = when (currentDialect) { + is SQLiteDialect -> rs.getObject(index) + else -> rs.getObject(index, OffsetDateTime::class.java) + } + return offsetDateTime + } + + override fun notNullValueToDB(value: Any): Any = when (value) { + is OffsetDateTime -> { + when (currentDialect) { + is SQLiteDialect -> value.format(SQLITE_OFFSET_DATE_TIME_FORMATTER) + is MysqlDialect -> value.format(MYSQL_OFFSET_DATE_TIME_FORMATTER) + else -> value + } + } + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + companion object { + internal val INSTANCE = JavaOffsetDateTimeColumnType() + } +} + class JavaDurationColumnType : ColumnType() { override fun sqlType(): String = currentDialect.dataTypeProvider.longType() @@ -308,6 +377,14 @@ fun Table.time(name: String): Column = registerColumn(name, JavaLocal */ fun Table.timestamp(name: String): Column = registerColumn(name, JavaInstantColumnType()) +/** + * A timestamp column to store both a date and a time with time zone. + * + * @param name The column name + */ +fun Table.timestampWithTimeZone(name: String): Column = + registerColumn(name, JavaOffsetDateTimeColumnType()) + /** * A date column to store a duration. * diff --git a/exposed-java-time/src/test/kotlin/org/jetbrains/exposed/JavaTimeTests.kt b/exposed-java-time/src/test/kotlin/org/jetbrains/exposed/JavaTimeTests.kt index 0e1a849d38..88bfb80be3 100644 --- a/exposed-java-time/src/test/kotlin/org/jetbrains/exposed/JavaTimeTests.kt +++ b/exposed-java-time/src/test/kotlin/org/jetbrains/exposed/JavaTimeTests.kt @@ -7,6 +7,7 @@ import kotlinx.serialization.encoding.Decoder import kotlinx.serialization.encoding.Encoder import kotlinx.serialization.json.Json import org.jetbrains.exposed.dao.id.IntIdTable +import org.jetbrains.exposed.exceptions.UnsupportedByDialectException import org.jetbrains.exposed.sql.* import org.jetbrains.exposed.sql.SqlExpressionBuilder.between import org.jetbrains.exposed.sql.SqlExpressionBuilder.eq @@ -17,6 +18,7 @@ import org.jetbrains.exposed.sql.tests.TestDB import org.jetbrains.exposed.sql.tests.currentDialectTest import org.jetbrains.exposed.sql.tests.shared.assertEquals import org.jetbrains.exposed.sql.tests.shared.assertTrue +import org.jetbrains.exposed.sql.tests.shared.expectException import org.jetbrains.exposed.sql.vendors.* import org.junit.Assert.fail import org.junit.Test @@ -26,8 +28,10 @@ import java.time.Instant import java.time.LocalDate import java.time.LocalDateTime import java.time.LocalTime -import java.time.ZoneOffset +import java.time.OffsetDateTime import java.time.temporal.Temporal +import java.time.ZoneId +import java.time.ZoneOffset import kotlin.test.assertEquals open class JavaTimeBaseTest : DatabaseTestsBase() { @@ -304,6 +308,95 @@ open class JavaTimeBaseTest : DatabaseTestsBase() { assertEquals(2, modifiedBeforeCreation[tester.modified].userId) } } + + @Test + fun testTimestampWithTimeZone() { + val testTable = object : IntIdTable("TestTable") { + val timestampWithTimeZone = timestampWithTimeZone("timestamptz-column") + } + + withDb(excludeSettings = listOf(TestDB.MARIADB)) { testDB -> + if (testDB != TestDB.MYSQL || db.isVersionCovers(BigDecimal("8.0"))) { + SchemaUtils.create(testTable) + + // Cairo time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone("Africa/Cairo")) + assertEquals("Africa/Cairo", ZoneId.systemDefault().id) + + val cairoNow = OffsetDateTime.now(ZoneId.systemDefault()) + + val cairoId = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInCairoTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + // UTC time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone(ZoneOffset.UTC)) + assertEquals("UTC", ZoneId.systemDefault().id) + + val cairoNowRetrievedInUTCTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + val utcID = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInUTCTimeZone = testTable.select { testTable.id eq utcID }.single()[testTable.timestampWithTimeZone] + + // Tokyo time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone("Asia/Tokyo")) + assertEquals("Asia/Tokyo", ZoneId.systemDefault().id) + + val cairoNowRetrievedInTokyoTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + val tokyoID = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInTokyoTimeZone = testTable.select { testTable.id eq tokyoID }.single()[testTable.timestampWithTimeZone] + + // PostgreSQL and MySQL always store the timestamp in UTC, thereby losing the original time zone. + // To preserve the original time zone, store the time zone information in a separate column. + val isOriginalTimeZonePreserved = testDB !in listOf( + TestDB.POSTGRESQL, + TestDB.POSTGRESQLNG, + TestDB.MYSQL + ) + if (isOriginalTimeZonePreserved) { + // Assert that time zone is preserved when the same value is inserted in different time zones + assertEqualDateTime(cairoNow, cairoNowInsertedInCairoTimeZone) + assertEqualDateTime(cairoNow, cairoNowInsertedInUTCTimeZone) + assertEqualDateTime(cairoNow, cairoNowInsertedInTokyoTimeZone) + + // Assert that time zone is preserved when the same record is retrieved in different time zones + assertEqualDateTime(cairoNow, cairoNowRetrievedInUTCTimeZone) + assertEqualDateTime(cairoNow, cairoNowRetrievedInTokyoTimeZone) + } else { + // Assert equivalence in UTC when the same value is inserted in different time zones + assertEqualDateTime(cairoNowInsertedInCairoTimeZone, cairoNowInsertedInUTCTimeZone) + assertEqualDateTime(cairoNowInsertedInUTCTimeZone, cairoNowInsertedInTokyoTimeZone) + + // Assert equivalence in UTC when the same record is retrieved in different time zones + assertEqualDateTime(cairoNowRetrievedInUTCTimeZone, cairoNowRetrievedInTokyoTimeZone) + } + } + } + } + + @Test + fun testTimestampWithTimeZoneThrowsExceptionForUnsupportedDialects() { + val testTable = object : IntIdTable("TestTable") { + val timestampWithTimeZone = timestampWithTimeZone("timestamptz-column") + } + + withDb(db = listOf(TestDB.MYSQL, TestDB.MARIADB)) { testDB -> + if (testDB == TestDB.MARIADB || !db.isVersionCovers(BigDecimal("8.0"))) { + expectException { + SchemaUtils.create(testTable) + } + } + } + } } fun assertEqualDateTime(d1: T?, d2: T?) { @@ -318,13 +411,21 @@ fun assertEqualDateTime(d1: T?, d2: T?) { } } d1 is LocalDateTime && d2 is LocalDateTime -> { - assertEquals(d1.toEpochSecond(ZoneOffset.UTC), d2.toEpochSecond(ZoneOffset.UTC), "Failed on epoch seconds ${currentDialectTest.name}") + assertEquals( + d1.toEpochSecond(ZoneOffset.UTC), + d2.toEpochSecond(ZoneOffset.UTC), + "Failed on epoch seconds ${currentDialectTest.name}" + ) assertEqualFractionalPart(d1.nano, d2.nano) } d1 is Instant && d2 is Instant -> { assertEquals(d1.epochSecond, d2.epochSecond, "Failed on epoch seconds ${currentDialectTest.name}") assertEqualFractionalPart(d1.nano, d2.nano) } + d1 is OffsetDateTime && d2 is OffsetDateTime -> { + assertEqualDateTime(d1.toLocalDateTime(), d2.toLocalDateTime()) + assertEquals(d1.offset, d2.offset) + } else -> assertEquals(d1, d2, "Failed on ${currentDialectTest.name}") } } diff --git a/exposed-kotlin-datetime/api/exposed-kotlin-datetime.api b/exposed-kotlin-datetime/api/exposed-kotlin-datetime.api index dc434d4506..36bb43646e 100644 --- a/exposed-kotlin-datetime/api/exposed-kotlin-datetime.api +++ b/exposed-kotlin-datetime/api/exposed-kotlin-datetime.api @@ -20,6 +20,7 @@ public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateColumnTyp public static final fun duration (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; public static final fun time (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; public static final fun timestamp (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; + public static final fun timestampWithTimeZone (Lorg/jetbrains/exposed/sql/Table;Ljava/lang/String;)Lorg/jetbrains/exposed/sql/Column; } public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateFunctionsKt { @@ -154,6 +155,21 @@ public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinLocalTimeColu public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinLocalTimeColumnType$Companion { } +public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinOffsetDateTimeColumnType : org/jetbrains/exposed/sql/ColumnType, org/jetbrains/exposed/sql/IDateColumnType { + public static final field Companion Lorg/jetbrains/exposed/sql/kotlin/datetime/KotlinOffsetDateTimeColumnType$Companion; + public fun ()V + public fun getHasTimePart ()Z + public fun nonNullValueToString (Ljava/lang/Object;)Ljava/lang/String; + public fun notNullValueToDB (Ljava/lang/Object;)Ljava/lang/Object; + public fun readObject (Ljava/sql/ResultSet;I)Ljava/lang/Object; + public fun sqlType ()Ljava/lang/String; + public synthetic fun valueFromDB (Ljava/lang/Object;)Ljava/lang/Object; + public fun valueFromDB (Ljava/lang/Object;)Ljava/time/OffsetDateTime; +} + +public final class org/jetbrains/exposed/sql/kotlin/datetime/KotlinOffsetDateTimeColumnType$Companion { +} + public final class org/jetbrains/exposed/sql/kotlin/datetime/YearInternal : org/jetbrains/exposed/sql/Function { public fun (Lorg/jetbrains/exposed/sql/Expression;)V public final fun getExpr ()Lorg/jetbrains/exposed/sql/Expression; diff --git a/exposed-kotlin-datetime/src/main/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateColumnType.kt b/exposed-kotlin-datetime/src/main/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateColumnType.kt index 0837c105d0..76eaba480b 100644 --- a/exposed-kotlin-datetime/src/main/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateColumnType.kt +++ b/exposed-kotlin-datetime/src/main/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinDateColumnType.kt @@ -9,11 +9,13 @@ import org.jetbrains.exposed.sql.ColumnType import org.jetbrains.exposed.sql.IDateColumnType import org.jetbrains.exposed.sql.Table import org.jetbrains.exposed.sql.vendors.H2Dialect +import org.jetbrains.exposed.sql.vendors.MysqlDialect import org.jetbrains.exposed.sql.vendors.OracleDialect import org.jetbrains.exposed.sql.vendors.SQLiteDialect import org.jetbrains.exposed.sql.vendors.currentDialect import org.jetbrains.exposed.sql.vendors.h2Mode import java.sql.ResultSet +import java.time.OffsetDateTime import java.time.ZoneId import java.time.format.DateTimeFormatter import java.util.* @@ -50,6 +52,25 @@ private val DEFAULT_TIME_STRING_FORMATTER by lazy { DateTimeFormatter.ISO_LOCAL_TIME.withLocale(Locale.ROOT).withZone(ZoneId.systemDefault()) } +// Example result: 2023-07-07 14:42:29.343+02:00 or 2023-07-07 12:42:29.343Z +internal val SQLITE_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ofPattern( + "yyyy-MM-dd HH:mm:ss.SSS[XXX]", + Locale.ROOT + ) +} + +internal val MYSQL_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ofPattern( + "yyyy-MM-dd HH:mm:ss.SSSSSS[XXX]", + Locale.ROOT + ) +} + +internal val DEFAULT_OFFSET_DATE_TIME_FORMATTER by lazy { + DateTimeFormatter.ISO_OFFSET_DATE_TIME.withLocale(Locale.ROOT) +} + private fun formatterForDateString(date: String) = dateTimeWithFractionFormat(date.substringAfterLast('.', "").length) private fun dateTimeWithFractionFormat(fraction: Int): DateTimeFormatter { val baseFormat = "yyyy-MM-d HH:mm:ss" @@ -251,6 +272,55 @@ class KotlinInstantColumnType : ColumnType(), IDateColumnType { } } +class KotlinOffsetDateTimeColumnType : ColumnType(), IDateColumnType { + override val hasTimePart: Boolean = true + + override fun sqlType(): String = currentDialect.dataTypeProvider.timestampWithTimeZoneType() + + override fun nonNullValueToString(value: Any): String = when (value) { + is OffsetDateTime -> { + when (currentDialect) { + is SQLiteDialect -> "'${value.format(SQLITE_OFFSET_DATE_TIME_FORMATTER)}'" + is MysqlDialect -> "'${value.format(MYSQL_OFFSET_DATE_TIME_FORMATTER)}'" + else -> "'${value.format(DEFAULT_OFFSET_DATE_TIME_FORMATTER)}'" + } + } + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + override fun valueFromDB(value: Any): OffsetDateTime = when (value) { + is OffsetDateTime -> value + is String -> OffsetDateTime.parse( + value, + if (currentDialect is MysqlDialect) MYSQL_OFFSET_DATE_TIME_FORMATTER else SQLITE_OFFSET_DATE_TIME_FORMATTER + ) + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + override fun readObject(rs: ResultSet, index: Int): Any? { + val offsetDateTime = when (currentDialect) { + is SQLiteDialect -> rs.getObject(index) + else -> rs.getObject(index, OffsetDateTime::class.java) + } + return offsetDateTime + } + + override fun notNullValueToDB(value: Any): Any = when (value) { + is OffsetDateTime -> { + when (currentDialect) { + is SQLiteDialect -> value.format(SQLITE_OFFSET_DATE_TIME_FORMATTER) + is MysqlDialect -> value.format(MYSQL_OFFSET_DATE_TIME_FORMATTER) + else -> value + } + } + else -> error("Unexpected value: $value of ${value::class.qualifiedName}") + } + + companion object { + internal val INSTANCE = KotlinOffsetDateTimeColumnType() + } +} + class KotlinDurationColumnType : ColumnType() { override fun sqlType(): String = currentDialect.dataTypeProvider.longType() @@ -320,6 +390,14 @@ fun Table.time(name: String): Column = registerColumn(name, KotlinLoc */ fun Table.timestamp(name: String): Column = registerColumn(name, KotlinInstantColumnType()) +/** + * A timestamp column to store both a date and a time with time zone. + * + * @param name The column name + */ +fun Table.timestampWithTimeZone(name: String): Column = + registerColumn(name, KotlinOffsetDateTimeColumnType()) + /** * A date column to store a duration. * diff --git a/exposed-kotlin-datetime/src/test/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinTimeTests.kt b/exposed-kotlin-datetime/src/test/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinTimeTests.kt index 361fa26026..47d8621b0a 100644 --- a/exposed-kotlin-datetime/src/test/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinTimeTests.kt +++ b/exposed-kotlin-datetime/src/test/kotlin/org/jetbrains/exposed/sql/kotlin/datetime/KotlinTimeTests.kt @@ -4,6 +4,7 @@ import kotlinx.datetime.* import kotlinx.serialization.Serializable import kotlinx.serialization.json.Json import org.jetbrains.exposed.dao.id.IntIdTable +import org.jetbrains.exposed.exceptions.UnsupportedByDialectException import org.jetbrains.exposed.sql.* import org.jetbrains.exposed.sql.SqlExpressionBuilder.between import org.jetbrains.exposed.sql.SqlExpressionBuilder.eq @@ -13,11 +14,14 @@ import org.jetbrains.exposed.sql.tests.TestDB import org.jetbrains.exposed.sql.tests.currentDialectTest import org.jetbrains.exposed.sql.tests.shared.assertEquals import org.jetbrains.exposed.sql.tests.shared.assertTrue +import org.jetbrains.exposed.sql.tests.shared.expectException import org.jetbrains.exposed.sql.vendors.* import org.junit.Assert.fail import org.junit.Test import java.math.BigDecimal import java.math.RoundingMode +import java.time.OffsetDateTime +import java.time.ZoneId import java.time.ZoneOffset import kotlin.test.assertEquals @@ -299,6 +303,95 @@ open class KotlinTimeBaseTest : DatabaseTestsBase() { assertEquals(2, modifiedBeforeCreation[tester.modified].userId) } } + + @Test + fun testTimestampWithTimeZone() { + val testTable = object : IntIdTable("TestTable") { + val timestampWithTimeZone = timestampWithTimeZone("timestamptz-column") + } + + withDb(excludeSettings = listOf(TestDB.MARIADB)) { testDB -> + if (testDB != TestDB.MYSQL || db.isVersionCovers(BigDecimal("8.0"))) { + SchemaUtils.create(testTable) + + // Cairo time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone("Africa/Cairo")) + assertEquals("Africa/Cairo", ZoneId.systemDefault().id) + + val cairoNow = OffsetDateTime.now(ZoneId.systemDefault()) + + val cairoId = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInCairoTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + // UTC time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone(ZoneOffset.UTC)) + assertEquals("UTC", ZoneId.systemDefault().id) + + val cairoNowRetrievedInUTCTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + val utcID = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInUTCTimeZone = testTable.select { testTable.id eq utcID }.single()[testTable.timestampWithTimeZone] + + // Tokyo time zone + java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone("Asia/Tokyo")) + assertEquals("Asia/Tokyo", ZoneId.systemDefault().id) + + val cairoNowRetrievedInTokyoTimeZone = testTable.select { testTable.id eq cairoId }.single()[testTable.timestampWithTimeZone] + + val tokyoID = testTable.insertAndGetId { + it[timestampWithTimeZone] = cairoNow + } + + val cairoNowInsertedInTokyoTimeZone = testTable.select { testTable.id eq tokyoID }.single()[testTable.timestampWithTimeZone] + + // PostgreSQL and MySQL always store the timestamp in UTC, thereby losing the original time zone. + // To preserve the original time zone, store the time zone information in a separate column. + val isOriginalTimeZonePreserved = testDB !in listOf( + TestDB.POSTGRESQL, + TestDB.POSTGRESQLNG, + TestDB.MYSQL + ) + if (isOriginalTimeZonePreserved) { + // Assert that time zone is preserved when the same value is inserted in different time zones + assertEqualDateTime(cairoNow, cairoNowInsertedInCairoTimeZone) + assertEqualDateTime(cairoNow, cairoNowInsertedInUTCTimeZone) + assertEqualDateTime(cairoNow, cairoNowInsertedInTokyoTimeZone) + + // Assert that time zone is preserved when the same record is retrieved in different time zones + assertEqualDateTime(cairoNow, cairoNowRetrievedInUTCTimeZone) + assertEqualDateTime(cairoNow, cairoNowRetrievedInTokyoTimeZone) + } else { + // Assert equivalence in UTC when the same value is inserted in different time zones + assertEqualDateTime(cairoNowInsertedInCairoTimeZone, cairoNowInsertedInUTCTimeZone) + assertEqualDateTime(cairoNowInsertedInUTCTimeZone, cairoNowInsertedInTokyoTimeZone) + + // Assert equivalence in UTC when the same record is retrieved in different time zones + assertEqualDateTime(cairoNowRetrievedInUTCTimeZone, cairoNowRetrievedInTokyoTimeZone) + } + } + } + } + + @Test + fun testTimestampWithTimeZoneThrowsExceptionForUnsupportedDialects() { + val testTable = object : IntIdTable("TestTable") { + val timestampWithTimeZone = timestampWithTimeZone("timestamptz-column") + } + + withDb(db = listOf(TestDB.MYSQL, TestDB.MARIADB)) { testDB -> + if (testDB == TestDB.MARIADB || !db.isVersionCovers(BigDecimal("8.0"))) { + expectException { + SchemaUtils.create(testTable) + } + } + } + } } fun assertEqualDateTime(d1: T?, d2: T?) { @@ -312,7 +405,6 @@ fun assertEqualDateTime(d1: T?, d2: T?) { assertEqualFractionalPart(d1.nanosecond, d2.nanosecond) } } - d1 is LocalDateTime && d2 is LocalDateTime -> { assertEquals( d1.toJavaLocalDateTime().toEpochSecond(ZoneOffset.UTC), @@ -321,12 +413,14 @@ fun assertEqualDateTime(d1: T?, d2: T?) { ) assertEqualFractionalPart(d1.nanosecond, d2.nanosecond) } - d1 is Instant && d2 is Instant -> { assertEquals(d1.epochSeconds, d2.epochSeconds, "Failed on epoch seconds ${currentDialectTest.name}") assertEqualFractionalPart(d1.nanosecondsOfSecond, d2.nanosecondsOfSecond) } - + d1 is OffsetDateTime && d2 is OffsetDateTime -> { + assertEqualDateTime(d1.toLocalDateTime().toKotlinLocalDateTime(), d2.toLocalDateTime().toKotlinLocalDateTime()) + assertEquals(d1.offset, d2.offset) + } else -> assertEquals(d1, d2, "Failed on ${currentDialectTest.name}") } }