Skip to content

Commit

Permalink
feat: EXPOSED-43 Add support for timestamp with time zone
Browse files Browse the repository at this point in the history
  • Loading branch information
joc-a committed Jul 24, 2023
1 parent fa38a77 commit cd7dbad
Show file tree
Hide file tree
Showing 20 changed files with 824 additions and 8 deletions.
2 changes: 2 additions & 0 deletions exposed-core/api/exposed-core.api
Original file line number Diff line number Diff line change
Expand Up @@ -3191,6 +3191,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;
Expand Down Expand Up @@ -3497,6 +3498,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;
}

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -91,6 +91,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"

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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'"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,17 @@ 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"
+ ((currentDialect as? MariaDBDialect)?.let { "" } ?: " for this version"),
currentDialect
)
}

override fun ubyteType(): String = "TINYINT UNSIGNED"

override fun ushortType(): String = "SMALLINT UNSIGNED"
Expand Down Expand Up @@ -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)")
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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"

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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"
Expand Down
19 changes: 19 additions & 0 deletions exposed-java-time/api/exposed-java-time.api
Original file line number Diff line number Diff line change
Expand Up @@ -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 {
Expand All @@ -46,6 +47,7 @@ public final class org/jetbrains/exposed/sql/javatime/JavaDateFunctionsKt {
public static final fun CustomDurationFunction (Ljava/lang/String;[Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/CustomFunction;
public static final fun CustomTimeFunction (Ljava/lang/String;[Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/CustomFunction;
public static final fun CustomTimeStampFunction (Ljava/lang/String;[Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/CustomFunction;
public static final fun CustomTimestampWithTimeZoneFunction (Ljava/lang/String;[Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/CustomFunction;
public static final fun date (Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/javatime/Date;
public static final fun dateLiteral (Ljava/time/LocalDate;)Lorg/jetbrains/exposed/sql/LiteralOp;
public static final fun dateParam (Ljava/time/LocalDate;)Lorg/jetbrains/exposed/sql/Expression;
Expand All @@ -62,6 +64,8 @@ public final class org/jetbrains/exposed/sql/javatime/JavaDateFunctionsKt {
public static final fun timeParam (Ljava/time/LocalTime;)Lorg/jetbrains/exposed/sql/Expression;
public static final fun timestampLiteral (Ljava/time/Instant;)Lorg/jetbrains/exposed/sql/LiteralOp;
public static final fun timestampParam (Ljava/time/Instant;)Lorg/jetbrains/exposed/sql/Expression;
public static final fun timestampWithTimeZoneLiteral (Ljava/time/OffsetDateTime;)Lorg/jetbrains/exposed/sql/LiteralOp;
public static final fun timestampWithTimeZoneParam (Ljava/time/OffsetDateTime;)Lorg/jetbrains/exposed/sql/Expression;
public static final fun year (Lorg/jetbrains/exposed/sql/Expression;)Lorg/jetbrains/exposed/sql/javatime/Year;
}

Expand Down Expand Up @@ -134,6 +138,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 <init> ()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 <init> (Lorg/jetbrains/exposed/sql/Expression;)V
public final fun getExpr ()Lorg/jetbrains/exposed/sql/Expression;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -38,6 +39,26 @@ 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
)
}

// For UTC time zone, MySQL rejects the 'Z' and will only accept the offset '+00:00'
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"
Expand Down Expand Up @@ -241,6 +262,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 -> {
if (currentDialect is SQLiteDialect) {
OffsetDateTime.parse(value, SQLITE_OFFSET_DATE_TIME_FORMATTER)
} else {
OffsetDateTime.parse(value)
}
}
else -> error("Unexpected value: $value of ${value::class.qualifiedName}")
}

override fun readObject(rs: ResultSet, index: Int): Any? = when (currentDialect) {
is SQLiteDialect -> super.readObject(rs, index)
else -> rs.getObject(index, OffsetDateTime::class.java)
}

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()

Expand Down Expand Up @@ -288,7 +358,7 @@ class JavaDurationColumnType : ColumnType() {
fun Table.date(name: String): Column<LocalDate> = registerColumn(name, JavaLocalDateColumnType())

/**
* A datetime column to store both a date and a time.
* A datetime column to store both a date and a time without time zone.
*
* @param name The column name
*/
Expand All @@ -305,12 +375,23 @@ fun Table.datetime(name: String): Column<LocalDateTime> = registerColumn(name, J
fun Table.time(name: String): Column<LocalTime> = registerColumn(name, JavaLocalTimeColumnType())

/**
* A timestamp column to store both a date and a time.
* A timestamp column to store both a date and a time without time zone.
*
* @param name The column name
*/
fun Table.timestamp(name: String): Column<Instant> = registerColumn(name, JavaInstantColumnType())

/**
* A timestamp column to store both a date and a time with time zone.
*
* Note: 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.
*
* @param name The column name
*/
fun Table.timestampWithTimeZone(name: String): Column<OffsetDateTime> =
registerColumn(name, JavaOffsetDateTimeColumnType())

/**
* A date column to store a duration.
*
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ import java.time.Instant
import java.time.LocalDate
import java.time.LocalDateTime
import java.time.LocalTime
import java.time.OffsetDateTime
import java.time.temporal.Temporal

class Date<T : Temporal?>(val expr: Expression<T>) : Function<LocalDate>(JavaLocalDateColumnType.INSTANCE) {
Expand Down Expand Up @@ -138,13 +139,19 @@ fun dateTimeParam(value: LocalDateTime): Expression<LocalDateTime> =
QueryParameter(value, JavaLocalDateTimeColumnType.INSTANCE)

fun timestampParam(value: Instant): Expression<Instant> = QueryParameter(value, JavaInstantColumnType.INSTANCE)

fun timestampWithTimeZoneParam(value: OffsetDateTime): Expression<OffsetDateTime> =
QueryParameter(value, JavaOffsetDateTimeColumnType.INSTANCE)

fun durationParam(value: Duration): Expression<Duration> = QueryParameter(value, JavaDurationColumnType.INSTANCE)

fun dateLiteral(value: LocalDate): LiteralOp<LocalDate> = LiteralOp(JavaLocalDateColumnType.INSTANCE, value)
fun timeLiteral(value: LocalTime): LiteralOp<LocalTime> = LiteralOp(JavaLocalTimeColumnType.INSTANCE, value)
fun dateTimeLiteral(value: LocalDateTime): LiteralOp<LocalDateTime> = LiteralOp(JavaLocalDateTimeColumnType.INSTANCE, value)

fun timestampLiteral(value: Instant): LiteralOp<Instant> = LiteralOp(JavaInstantColumnType.INSTANCE, value)
fun timestampWithTimeZoneLiteral(value: OffsetDateTime): LiteralOp<OffsetDateTime> =
LiteralOp(JavaOffsetDateTimeColumnType.INSTANCE, value)
fun durationLiteral(value: Duration): LiteralOp<Duration> = LiteralOp(JavaDurationColumnType.INSTANCE, value)

@Suppress("FunctionName")
Expand All @@ -163,6 +170,12 @@ fun CustomDateTimeFunction(functionName: String, vararg params: Expression<*>):
fun CustomTimeStampFunction(functionName: String, vararg params: Expression<*>): CustomFunction<Instant?> =
CustomFunction(functionName, JavaInstantColumnType.INSTANCE, *params)

@Suppress("FunctionName")
fun CustomTimestampWithTimeZoneFunction(
functionName: String,
vararg params: Expression<*>
): CustomFunction<OffsetDateTime?> = CustomFunction(functionName, JavaOffsetDateTimeColumnType.INSTANCE, *params)

@Suppress("FunctionName")
fun CustomDurationFunction(functionName: String, vararg params: Expression<*>): CustomFunction<Duration?> =
CustomFunction(functionName, JavaDurationColumnType.INSTANCE, *params)
Original file line number Diff line number Diff line change
Expand Up @@ -287,6 +287,61 @@ class DefaultsTest : DatabaseTestsBase() {
}
}

@Test
fun testTimestampWithTimeZoneDefaults() {
// UTC time zone
java.util.TimeZone.setDefault(java.util.TimeZone.getTimeZone(ZoneOffset.UTC))
assertEquals("UTC", ZoneId.systemDefault().id)

val nowWithTimeZone = OffsetDateTime.now()
val timestampWithTimeZoneLiteral = timestampWithTimeZoneLiteral(nowWithTimeZone)

val testTable = object : IntIdTable("t") {
val t1 = timestampWithTimeZone("t1").default(nowWithTimeZone)
val t2 = timestampWithTimeZone("t2").defaultExpression(timestampWithTimeZoneLiteral)
}

fun Expression<*>.itOrNull() = when {
currentDialectTest.isAllowedAsColumnDefault(this) ->
"DEFAULT ${currentDialectTest.dataTypeProvider.processForDefaultValue(this)} NOT NULL"
else -> "NULL"
}

withDb(excludeSettings = listOf(TestDB.SQLITE, TestDB.MARIADB)) {
if (!isOldMySql()) {
SchemaUtils.create(testTable)

val timestampWithTimeZoneType = currentDialectTest.dataTypeProvider.timestampWithTimeZoneType()

val baseExpression = "CREATE TABLE " + addIfNotExistsIfSupported() +
"${"t".inProperCase()} (" +
"${"id".inProperCase()} ${currentDialectTest.dataTypeProvider.integerAutoincType()} PRIMARY KEY, " +
"${"t1".inProperCase()} $timestampWithTimeZoneType ${timestampWithTimeZoneLiteral.itOrNull()}, " +
"${"t2".inProperCase()} $timestampWithTimeZoneType ${timestampWithTimeZoneLiteral.itOrNull()}" +
")"

val expected = if (currentDialectTest is OracleDialect ||
currentDialectTest.h2Mode == H2Dialect.H2CompatibilityMode.Oracle
) {
arrayListOf(
"CREATE SEQUENCE t_id_seq START WITH 1 MINVALUE 1 MAXVALUE 9223372036854775807",
baseExpression
)
} else {
arrayListOf(baseExpression)
}

assertEqualLists(expected, testTable.ddl)

val id1 = testTable.insertAndGetId { }

val row1 = testTable.select { testTable.id eq id1 }.single()
assertEqualDateTime(nowWithTimeZone, row1[testTable.t1])
assertEqualDateTime(nowWithTimeZone, row1[testTable.t2])
}
}
}

@Test
fun testDefaultExpressions01() {
fun abs(value: Int) = object : ExpressionWithColumnType<Int>() {
Expand Down
Loading

0 comments on commit cd7dbad

Please sign in to comment.