From 6bb8711dd3b5cfc671931081bf850f7d7aa1888a Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?griff=20=D1=96=E2=8A=99?= <346896+griffio@users.noreply.github.com> Date: Wed, 17 Jul 2024 14:10:19 +0100 Subject: [PATCH] Add 5273 Postrgesql extract from temporal types (#5274) * Add Postgresql EXTRACT function extract temporal fields * Add tests fixture test integration test * Integration Test todo - bind arg test "?" needs cast e.g `?::TIMESTAMP` * Add TIME and DATE literals Add Support for: SELECT EXTRACT(MONTH FROM DATE '2023-05-15'); SELECT EXTRACT(HOUR FROM TIME '10:30:45'); * Update Test.s SELECT EXTRACT(MONTH FROM DATE '2023-05-15'); SELECT EXTRACT(HOUR FROM TIME '10:30:45'); * Add date and time literals To support Extract * Date and Time tests Literal Date and Time tests * Add Date and Time test Integration Test for Extract * Update PostgreSqlTypeResolver.kt Add error to validate temporal types * Add Interval test Integration test for INTERVAL returns double(3) * Update PostgreSql.bnf Add latest temporal fields (22) --- .../postgresql/PostgreSqlTypeResolver.kt | 20 ++++++++++-- .../postgresql/grammar/PostgreSql.bnf | 21 +++++++++++-- .../mixins/ExtractTemporalExpressionMixin.kt | 18 +++++++++++ .../extract-expressions/Test.s | 16 ++++++++++ .../postgresql/integration/Dates.sq | 7 +++++ .../postgresql/integration/Extract.sq | 21 +++++++++++++ .../postgresql/integration/PostgreSqlTest.kt | 31 +++++++++++++++++++ 7 files changed, 129 insertions(+), 5 deletions(-) create mode 100644 dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/mixins/ExtractTemporalExpressionMixin.kt create mode 100644 dialects/postgresql/src/testFixtures/resources/fixtures_postgresql/extract-expressions/Test.s create mode 100644 sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Extract.sq diff --git a/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/PostgreSqlTypeResolver.kt b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/PostgreSqlTypeResolver.kt index 52281f727f9..85eb7207460 100644 --- a/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/PostgreSqlTypeResolver.kt +++ b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/PostgreSqlTypeResolver.kt @@ -20,6 +20,7 @@ import app.cash.sqldelight.dialects.postgresql.PostgreSqlType.TIMESTAMP_TIMEZONE import app.cash.sqldelight.dialects.postgresql.grammar.mixins.AggregateExpressionMixin import app.cash.sqldelight.dialects.postgresql.grammar.mixins.AtTimeZoneOperatorExpressionMixin import app.cash.sqldelight.dialects.postgresql.grammar.mixins.DoubleColonCastOperatorExpressionMixin +import app.cash.sqldelight.dialects.postgresql.grammar.mixins.ExtractTemporalExpressionMixin import app.cash.sqldelight.dialects.postgresql.grammar.mixins.WindowFunctionMixin import app.cash.sqldelight.dialects.postgresql.grammar.psi.PostgreSqlAtTimeZoneOperator import app.cash.sqldelight.dialects.postgresql.grammar.psi.PostgreSqlDeleteStmtLimited @@ -280,8 +281,8 @@ class PostgreSqlTypeResolver(private val parentResolver: TypeResolver) : TypeRes } is SqlLiteralExpr -> when { literalValue.text == "TRUE" || literalValue.text == "FALSE" -> IntermediateType(BOOLEAN) - literalValue.text == "CURRENT_DATE" -> IntermediateType(PostgreSqlType.DATE) - literalValue.text == "CURRENT_TIME" -> IntermediateType(PostgreSqlType.TIME) + literalValue.text == "CURRENT_DATE" || literalValue.text.startsWith("DATE ") -> IntermediateType(PostgreSqlType.DATE) + literalValue.text == "CURRENT_TIME" || literalValue.text.startsWith("TIME ") -> IntermediateType(PostgreSqlType.TIME) literalValue.text.startsWith("CURRENT_TIMESTAMP") -> IntermediateType(PostgreSqlType.TIMESTAMP_TIMEZONE) literalValue.text.startsWith("TIMESTAMP WITH TIME ZONE") -> IntermediateType(PostgreSqlType.TIMESTAMP_TIMEZONE) literalValue.text.startsWith("TIMESTAMP WITHOUT TIME ZONE") -> IntermediateType(TIMESTAMP) @@ -323,6 +324,13 @@ class PostgreSqlTypeResolver(private val parentResolver: TypeResolver) : TypeRes val lastTypeCast = doubleColonCastOperatorExpression!!.doubleColonCastOperatorList.last().typeName definitionType(lastTypeCast).nullableIf(expType.javaType.isNullable) } + extractTemporalExpression != null -> { + val temporalExprType = (extractTemporalExpression as ExtractTemporalExpressionMixin).expr.postgreSqlType() + if (temporalExprType.dialectType !in temporalTypes) { + error("EXTRACT FROM requires a temporal type argument. The provided argument ${temporalExprType.dialectType} is not supported.") + } + IntermediateType(REAL).nullableIf(temporalExprType.javaType.isNullable) + } else -> parentResolver.resolvedType(this) } @@ -343,6 +351,14 @@ class PostgreSqlTypeResolver(private val parentResolver: TypeResolver) : TypeRes SqlTypes.LTE, ) + private val temporalTypes = listOf( + DATE, + PostgreSqlType.INTERVAL, + PostgreSqlType.TIMESTAMP_TIMEZONE, + PostgreSqlType.TIMESTAMP, + PostgreSqlType.TIME, + ) + private fun arrayIntermediateType(type: IntermediateType): IntermediateType { return IntermediateType( object : DialectType { diff --git a/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/PostgreSql.bnf b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/PostgreSql.bnf index 8e5e2ef7cb8..7f0e9fe3d8d 100644 --- a/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/PostgreSql.bnf +++ b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/PostgreSql.bnf @@ -240,10 +240,14 @@ tsvector_data_type ::= 'TSVECTOR' xml_data_type ::= 'XML' -interval_expression ::= 'INTERVAL' string_literal +interval_expression ::= 'INTERVAL' {string_literal} timestamp_expression ::= 'TIMESTAMP' [ (WITH | WITHOUT) 'TIME' 'ZONE' ] {string_literal} +date_expression ::= 'DATE' {string_literal} + +time_expression ::= 'TIME' {string_literal} + with_clause_auxiliary_stmt ::= {compound_select_stmt} | delete_stmt_limited | insert_stmt | update_stmt_limited { extends = "com.alecstrong.sql.psi.core.psi.impl.SqlWithClauseAuxiliaryStmtImpl" implements = "com.alecstrong.sql.psi.core.psi.SqlWithClauseAuxiliaryStmt" @@ -278,7 +282,9 @@ literal_value ::= ( {numeric_literal} | boolean_literal | current_date_time_functions | interval_expression - | timestamp_expression) { + | timestamp_expression + | date_expression + | time_expression ) { mixin = "app.cash.sqldelight.dialects.postgresql.grammar.mixins.LiteralValueMixin" implements = "com.alecstrong.sql.psi.core.psi.SqlLiteralValue" override = true @@ -410,7 +416,7 @@ compound_select_stmt ::= [ {with_clause} ] {select_stmt} ( {compound_operator} override = true } -extension_expr ::= double_colon_cast_operator_expression | contains_operator_expression | at_time_zone_operator_expression | regex_match_operator_expression | match_operator_expression | array_agg_stmt| string_agg_stmt | json_expression | boolean_not_expression | window_function_expr { +extension_expr ::= extract_temporal_expression | double_colon_cast_operator_expression | contains_operator_expression | at_time_zone_operator_expression | regex_match_operator_expression | match_operator_expression | array_agg_stmt| string_agg_stmt | json_expression | boolean_not_expression | window_function_expr { extends = "com.alecstrong.sql.psi.core.psi.impl.SqlExtensionExprImpl" implements = "com.alecstrong.sql.psi.core.psi.SqlExtensionExpr" override = true @@ -596,3 +602,12 @@ ordering_term ::= <> [ ASC | DESC ] [ 'NULLS' ( 'FIRST' | 'LAST' ) ] implements = "com.alecstrong.sql.psi.core.psi.SqlOrderingTerm" override = true } + +extract_temporal_field ::= 'century' | 'day' | 'decade' | 'dow' | 'doy' | 'epoch' | 'hour' | 'isodow' | 'isoyear' | 'julian' + | 'microseconds' | 'millennium' | 'milliseconds' | 'minute' | 'month' | 'quarter' | 'second' | 'timezone' | 'timezone_hour' + | 'timezone_minute' | 'week' | 'year' + +extract_temporal_expression ::= 'EXTRACT' LP extract_temporal_field FROM <> RP { + mixin = "app.cash.sqldelight.dialects.postgresql.grammar.mixins.ExtractTemporalExpressionMixin" + pin = 2 +} diff --git a/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/mixins/ExtractTemporalExpressionMixin.kt b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/mixins/ExtractTemporalExpressionMixin.kt new file mode 100644 index 00000000000..ca5318817a6 --- /dev/null +++ b/dialects/postgresql/src/main/kotlin/app/cash/sqldelight/dialects/postgresql/grammar/mixins/ExtractTemporalExpressionMixin.kt @@ -0,0 +1,18 @@ +package app.cash.sqldelight.dialects.postgresql.grammar.mixins + +import app.cash.sqldelight.dialects.postgresql.grammar.psi.PostgreSqlExtractTemporalExpression +import com.alecstrong.sql.psi.core.psi.SqlCompositeElementImpl +import com.alecstrong.sql.psi.core.psi.SqlExpr +import com.intellij.lang.ASTNode + +/** + * e.g access expr node for nullable type see `PostgreSqlTypeResolver extractTemporalExpression` + * EXTRACT(HOUR FROM TIME '10:30:45'), + * EXTRACT(DAY FROM created_date) + */ +internal abstract class ExtractTemporalExpressionMixin(node: ASTNode) : + SqlCompositeElementImpl(node), + SqlExpr, + PostgreSqlExtractTemporalExpression { + val expr get() = children.filterIsInstance().first() +} diff --git a/dialects/postgresql/src/testFixtures/resources/fixtures_postgresql/extract-expressions/Test.s b/dialects/postgresql/src/testFixtures/resources/fixtures_postgresql/extract-expressions/Test.s new file mode 100644 index 00000000000..befbc821dca --- /dev/null +++ b/dialects/postgresql/src/testFixtures/resources/fixtures_postgresql/extract-expressions/Test.s @@ -0,0 +1,16 @@ +CREATE TABLE Events( + start_at TIMESTAMPTZ NOT NULL CHECK(date_part('minute', start_at) IN (00,30)), + end_at TIMESTAMPTZ NOT NULL CHECK(date_part('minute', end_at) IN (00,30)), + duration INT GENERATED ALWAYS AS (EXTRACT(epoch FROM end_at - start_at)/ 60) stored, + created_date DATE +); + +SELECT EXTRACT(YEAR FROM TIMESTAMP '2023-05-15 10:30:45'); + +SELECT EXTRACT(MONTH FROM DATE '2023-05-15'); + +SELECT EXTRACT(HOUR FROM TIME '10:30:45'); + +SELECT EXTRACT(EPOCH FROM INTERVAL '1 day 2 hours'); + +SELECT EXTRACT(HOUR FROM created_date) FROM Events; diff --git a/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Dates.sq b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Dates.sq index 16d3ff00d68..46175a476fe 100644 --- a/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Dates.sq +++ b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Dates.sq @@ -42,3 +42,10 @@ SELECT max(date) FROM dates; selectMinDate: SELECT min(date) FROM dates; + +selectDateLiteral: +SELECT DATE '2023-05-15'; + +selectTimeLiteral: +SELECT TIME '10:30:45'; + diff --git a/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Extract.sq b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Extract.sq new file mode 100644 index 00000000000..f1a872d8aa5 --- /dev/null +++ b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/main/sqldelight/app/cash/sqldelight/postgresql/integration/Extract.sq @@ -0,0 +1,21 @@ +CREATE TABLE Events( + start_at TIMESTAMPTZ NOT NULL CHECK(date_part('minute', start_at) IN (00,30)), + end_at TIMESTAMPTZ NOT NULL CHECK(date_part('minute', end_at) IN (00,30)), + duration INT GENERATED ALWAYS AS (EXTRACT(epoch FROM end_at - start_at)/ 60) stored, + created_date DATE +); + +select: +SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40'), + EXTRACT(YEAR FROM TIMESTAMP '2023-05-15 10:30:45'), + EXTRACT(EPOCH FROM INTERVAL '1 day 2 hours'), + EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13'), + EXTRACT(MINUTE FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08'), + EXTRACT(DAY FROM created_date), + EXTRACT(MONTH FROM DATE '2023-05-15'), + EXTRACT(HOUR FROM TIME '10:30:45'), + EXTRACT(MONTH FROM INTERVAL '2 years 3 months') +FROM Events; + +insert: +INSERT INTO Events (start_at, end_at, created_date) VALUES (?, ?, ?); diff --git a/sqldelight-gradle-plugin/src/test/integration-postgresql/src/test/kotlin/app/cash/sqldelight/postgresql/integration/PostgreSqlTest.kt b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/test/kotlin/app/cash/sqldelight/postgresql/integration/PostgreSqlTest.kt index 7a09ff13168..f6590ab7bc6 100644 --- a/sqldelight-gradle-plugin/src/test/integration-postgresql/src/test/kotlin/app/cash/sqldelight/postgresql/integration/PostgreSqlTest.kt +++ b/sqldelight-gradle-plugin/src/test/integration-postgresql/src/test/kotlin/app/cash/sqldelight/postgresql/integration/PostgreSqlTest.kt @@ -423,6 +423,16 @@ class PostgreSqlTest { assertThat(now).isGreaterThan(OffsetDateTime.MIN) } + @Test fun testDateLiteral() { + val dateLiteral = database.datesQueries.selectDateLiteral().executeAsOne() + assertThat(dateLiteral).isEqualTo(LocalDate.of(2023, 5, 15)) + } + + @Test fun testTimeLiteral() { + val timeLiteral = database.datesQueries.selectTimeLiteral().executeAsOne() + assertThat(timeLiteral).isEqualTo(LocalTime.of(10, 30, 45, 0)) + } + @Test fun nowPlusInterval() { val selectNowInterval = database.datesQueries.selectNowInterval().executeAsOne() assertThat(selectNowInterval.now).isNotNull() @@ -1038,6 +1048,27 @@ class PostgreSqlTest { } } + @Test + fun testExtract() { + val sa = OffsetDateTime.of(2001, 2, 16, 19, 30, 0, 0, ZoneOffset.ofHours(0)) + val ea = OffsetDateTime.of(2001, 2, 16, 20, 30, 0, 0, ZoneOffset.ofHours(0)) + val cd = LocalDate.of(2001, 2, 16) + + database.extractQueries.insert(sa, ea, cd) + + with(database.extractQueries.select().executeAsOne()) { + assertThat(expr).isEqualTo(5) + assertThat(expr_).isEqualTo(2023) + assertThat(expr__).isEqualTo(93600) + assertThat(expr___).isEqualTo(20) + assertThat(expr____).isEqualTo(38) + assertThat(expr_____).isEqualTo(16) + assertThat(expr______).isEqualTo(5) + assertThat(expr_______).isEqualTo(10) + assertThat(expr________).isEqualTo(3) + } + } + @Test fun testSelectDistinctOn() { val studentExpected = Student(1000, "Test Student")