From 97957fdbaa429c7c582d4753b108cb1e23e1b28a Mon Sep 17 00:00:00 2001 From: Michael Paquier Date: Fri, 13 Oct 2023 13:01:37 +0900 Subject: [PATCH] Add support for AT LOCAL When converting a timestamp to/from with/without time zone, the SQL Standard specifies an AT LOCAL variant of AT TIME ZONE which uses the session's time zone. This includes three system functions able to do the work in the same way as the existing flavors for AT TIME ZONE, except that these need to be marked as stable as they depend on the session's TimeZone GUC. Bump catalog version. Author: Vik Fearing Reviewed-by: Laurenz Albe, Cary Huang, Michael Paquier Discussion: https://postgr.es/m/8e25dec4-5667-c1a5-6581-167d710c2182@postgresfriends.org --- doc/src/sgml/func.sgml | 97 ++++++++++++++++++++++- src/backend/parser/gram.y | 7 ++ src/backend/utils/adt/date.c | 15 ++++ src/backend/utils/adt/ruleutils.c | 10 +++ src/backend/utils/adt/timestamp.c | 20 +++++ src/include/catalog/catversion.h | 2 +- src/include/catalog/pg_proc.dat | 9 +++ src/test/regress/expected/timestamptz.out | 56 +++++++++++++ src/test/regress/expected/timetz.out | 42 ++++++++++ src/test/regress/sql/timestamptz.sql | 23 ++++++ src/test/regress/sql/timetz.sql | 17 ++++ 11 files changed, 294 insertions(+), 4 deletions(-) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 0769824e46..affd1254bb 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -10611,7 +10611,7 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 - <literal>AT TIME ZONE</literal> + <literal>AT TIME ZONE and AT LOCAL</literal> time zone @@ -10622,6 +10622,10 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 AT TIME ZONE + + AT LOCAL + + The AT TIME ZONE operator converts time stamp without time zone to/from @@ -10632,7 +10636,7 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 - <literal>AT TIME ZONE</literal> Variants + <literal>AT TIME ZONE</literal> and <literal>AT LOCAL</literal> Variants @@ -10665,6 +10669,22 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 + + + timestamp without time zone AT LOCAL + timestamp with time zone + + + Converts given time stamp without time zone to + time stamp with the session's + TimeZone value as time zone. + + + timestamp '2001-02-16 20:38:40' at local + 2001-02-17 03:38:40+00 + + + timestamp with time zone AT TIME ZONE zone @@ -10681,6 +10701,22 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 + + + timestamp with time zone AT LOCAL + timestamp without time zone + + + Converts given time stamp with time zone to + time stamp without time zone, as the time would + appear with the session's TimeZone value as time zone. + + + timestamp with time zone '2001-02-16 20:38:40-05' at local + 2001-02-16 18:38:40 + + + time with time zone AT TIME ZONE zone @@ -10696,6 +10732,25 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 10:34:17+00 + + + + time with time zone AT LOCAL + time with time zone + + + Converts given time with time zone to a new time + zone. Since no date is supplied, this uses the currently active UTC + offset for the session's TimeZone value. + + + Assuming the session's TimeZone is set to UTC: + + + time with time zone '05:34:17-05' at local + 10:34:17+00 + +
@@ -10710,6 +10765,13 @@ SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-0 UTC, so it is not very common in practice. + + The syntax AT LOCAL may be used as shorthand for + AT TIME ZONE local, where + local is the session's + TimeZone value. + + Examples (assuming the current setting is America/Los_Angeles): @@ -10722,6 +10784,12 @@ SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/D SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago'; Result: 2001-02-16 05:38:40 + +SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT LOCAL; +Result: 2001-02-16 17:38:40 + +SELECT TIME WITH TIME ZONE '20:38:40-05' AT LOCAL; +Result: 17:38:40 The first example adds a time zone to a value that lacks it, and displays the value using the current TimeZone @@ -10729,7 +10797,18 @@ SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'A to the specified time zone, and returns the value without a time zone. This allows storage and display of values different from the current TimeZone setting. The third example converts - Tokyo time to Chicago time. + Tokyo time to Chicago time. The fourth example shifts the time stamp + with time zone value to the time zone currently specified by the + TimeZone setting and returns the value without a + time zone. + + + + The fifth example is a cautionary tale. Due to the fact that there is no + date associated with the input value, the conversion is made using the + current date of the session. Therefore, this static example may show a wrong + result depending on the time of the year it is viewed because + 'America/Los_Angeles' observes Daylight Savings Time. @@ -10745,6 +10824,18 @@ SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'A time AT TIME ZONE zone. + + + The function timezone(timestamp) + is equivalent to the SQL-conforming construct timestamp + AT LOCAL. + + + + The function timezone(time) + is equivalent to the SQL-conforming construct time + AT LOCAL. +
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index e56cbe77cb..50ed504e5a 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -14508,6 +14508,13 @@ a_expr: c_expr { $$ = $1; } COERCE_SQL_SYNTAX, @2); } + | a_expr AT LOCAL %prec AT + { + $$ = (Node *) makeFuncCall(SystemFuncName("timezone"), + list_make1($1), + COERCE_SQL_SYNTAX, + -1); + } /* * These operators must be called out explicitly in order to make use * of bison's automatic operator-precedence handling. All other diff --git a/src/backend/utils/adt/date.c b/src/backend/utils/adt/date.c index ae0f24de2c..c4da10d47a 100644 --- a/src/backend/utils/adt/date.c +++ b/src/backend/utils/adt/date.c @@ -3125,3 +3125,18 @@ timetz_izone(PG_FUNCTION_ARGS) PG_RETURN_TIMETZADT_P(result); } + +/* timetz_at_local() + * + * Unlike for timestamp[tz]_at_local, the type for timetz does not flip between + * time with/without time zone, so we cannot just call the conversion function. + */ +Datum +timetz_at_local(PG_FUNCTION_ARGS) +{ + Datum time = PG_GETARG_DATUM(0); + const char *tzn = pg_get_timezone_name(session_timezone); + Datum zone = PointerGetDatum(cstring_to_text(tzn)); + + return DirectFunctionCall2(timetz_zone, zone, time); +} diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index 442205382e..ed7f40f053 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -10347,6 +10347,16 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context) appendStringInfoChar(buf, ')'); return true; + case F_TIMEZONE_TIMESTAMP: + case F_TIMEZONE_TIMESTAMPTZ: + case F_TIMEZONE_TIMETZ: + /* AT LOCAL */ + appendStringInfoChar(buf, '('); + get_rule_expr_paren((Node *) linitial(expr->args), context, false, + (Node *) expr); + appendStringInfoString(buf, " AT LOCAL)"); + return true; + case F_OVERLAPS_TIMESTAMPTZ_INTERVAL_TIMESTAMPTZ_INTERVAL: case F_OVERLAPS_TIMESTAMPTZ_INTERVAL_TIMESTAMPTZ_TIMESTAMPTZ: case F_OVERLAPS_TIMESTAMPTZ_TIMESTAMPTZ_TIMESTAMPTZ_INTERVAL: diff --git a/src/backend/utils/adt/timestamp.c b/src/backend/utils/adt/timestamp.c index 0e50aaec5a..e172e90614 100644 --- a/src/backend/utils/adt/timestamp.c +++ b/src/backend/utils/adt/timestamp.c @@ -5921,3 +5921,23 @@ generate_series_timestamptz_at_zone(PG_FUNCTION_ARGS) { return generate_series_timestamptz_internal(fcinfo); } + +/* timestamp_at_local() + * timestamptz_at_local() + * + * The regression tests do not like two functions with the same proargs and + * prosrc but different proname, but the grammar for AT LOCAL needs an + * overloaded name to handle both types of timestamp, so we make simple + * wrappers for it. + */ +Datum +timestamp_at_local(PG_FUNCTION_ARGS) +{ + return timestamp_timestamptz(fcinfo); +} + +Datum +timestamptz_at_local(PG_FUNCTION_ARGS) +{ + return timestamptz_timestamp(fcinfo); +} diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index 7d65feaef0..473687419c 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -57,6 +57,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 202309251 +#define CATALOG_VERSION_NO 202310131 #endif diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index f0b7b9cbd8..72ea4aa8b8 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -2319,6 +2319,9 @@ { oid => '1159', descr => 'adjust timestamp to new time zone', proname => 'timezone', prorettype => 'timestamp', proargtypes => 'text timestamptz', prosrc => 'timestamptz_zone' }, +{ oid => '9159', descr => 'adjust timestamp to local time zone', + proname => 'timezone', provolatile => 's', prorettype => 'timestamp', + proargtypes => 'timestamptz', prosrc => 'timestamptz_at_local' }, { oid => '1160', descr => 'I/O', proname => 'interval_in', provolatile => 's', prorettype => 'interval', @@ -6095,6 +6098,9 @@ { oid => '2038', descr => 'adjust time with time zone to new zone', proname => 'timezone', prorettype => 'timetz', proargtypes => 'interval timetz', prosrc => 'timetz_izone' }, +{ oid => '9161', descr => 'adjust time to local time zone', + proname => 'timezone', provolatile => 's', prorettype => 'timetz', + proargtypes => 'timetz', prosrc => 'timetz_at_local' }, { oid => '2039', descr => 'hash', proname => 'timestamp_hash', prorettype => 'int4', proargtypes => 'timestamp', prosrc => 'timestamp_hash' }, @@ -6190,6 +6196,9 @@ { oid => '2070', descr => 'adjust timestamp to new time zone', proname => 'timezone', prorettype => 'timestamptz', proargtypes => 'interval timestamp', prosrc => 'timestamp_izone' }, +{ oid => '9160', descr => 'adjust timestamp to local time zone', + proname => 'timezone', provolatile => 's', prorettype => 'timestamptz', + proargtypes => 'timestamp', prosrc => 'timestamp_at_local' }, { oid => '2071', proname => 'date_pl_interval', prorettype => 'timestamp', proargtypes => 'date interval', prosrc => 'date_pl_interval' }, diff --git a/src/test/regress/expected/timestamptz.out b/src/test/regress/expected/timestamptz.out index 0dd2fe2c82..2ca2101dd4 100644 --- a/src/test/regress/expected/timestamptz.out +++ b/src/test/regress/expected/timestamptz.out @@ -3135,6 +3135,62 @@ SELECT '2014-10-25 23:00:00 UTC'::timestamptz AT TIME ZONE 'MSK'; Sun Oct 26 02:00:00 2014 (1 row) +-- +-- Test LOCAL time zone +-- +BEGIN; +SET LOCAL TIME ZONE 'Europe/Paris'; +VALUES (CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL); + column1 +-------------------------- + Sat Jul 08 01:38:00 1978 +(1 row) + +VALUES (TIMESTAMP '1978-07-07 19:38' AT LOCAL); + column1 +------------------------------- + Fri Jul 07 19:38:00 1978 CEST +(1 row) + +SET LOCAL TIME ZONE 'Australia/Sydney'; +VALUES (CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL); + column1 +-------------------------- + Sat Jul 08 09:38:00 1978 +(1 row) + +VALUES (TIMESTAMP '1978-07-07 19:38' AT LOCAL); + column1 +------------------------------- + Fri Jul 07 19:38:00 1978 AEST +(1 row) + +SET LOCAL TimeZone TO 'UTC'; +CREATE VIEW timestamp_local_view AS + SELECT CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL AS ttz_at_local, + timezone(CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE)) AS ttz_func, + TIMESTAMP '1978-07-07 19:38' AT LOCAL AS t_at_local, + timezone(TIMESTAMP '1978-07-07 19:38') AS t_func; +SELECT pg_get_viewdef('timestamp_local_view', true); + pg_get_viewdef +---------------------------------------------------------------------------------------------- + SELECT ('Fri Jul 07 23:38:00 1978 UTC'::timestamp with time zone AT LOCAL) AS ttz_at_local,+ + timezone('Fri Jul 07 23:38:00 1978 UTC'::timestamp with time zone) AS ttz_func, + + ('Fri Jul 07 19:38:00 1978'::timestamp without time zone AT LOCAL) AS t_at_local, + + timezone('Fri Jul 07 19:38:00 1978'::timestamp without time zone) AS t_func; +(1 row) + +\x +TABLE timestamp_local_view; +-[ RECORD 1 ]+----------------------------- +ttz_at_local | Fri Jul 07 23:38:00 1978 +ttz_func | Fri Jul 07 23:38:00 1978 +t_at_local | Fri Jul 07 19:38:00 1978 UTC +t_func | Fri Jul 07 19:38:00 1978 UTC + +\x +DROP VIEW timestamp_local_view; +COMMIT; -- -- Test that AT TIME ZONE isn't misoptimized when using an index (bug #14504) -- diff --git a/src/test/regress/expected/timetz.out b/src/test/regress/expected/timetz.out index be49588b6d..7293c3bbb7 100644 --- a/src/test/regress/expected/timetz.out +++ b/src/test/regress/expected/timetz.out @@ -262,3 +262,45 @@ SELECT date_part('epoch', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401- 63025.575401 (1 row) +-- +-- AT LOCAL with timetz +-- +BEGIN; +SET LOCAL TimeZone TO 'UTC'; +CREATE VIEW timetz_local_view AS + SELECT f1 AS dat, + timezone(f1) AS dat_func, + f1 AT LOCAL AS dat_at_local, + f1 AT TIME ZONE current_setting('TimeZone') AS dat_at_time + FROM TIMETZ_TBL + ORDER BY f1; +SELECT pg_get_viewdef('timetz_local_view', true); + pg_get_viewdef +------------------------------------------------------------------------ + SELECT f1 AS dat, + + timezone(f1) AS dat_func, + + (f1 AT LOCAL) AS dat_at_local, + + (f1 AT TIME ZONE current_setting('TimeZone'::text)) AS dat_at_time+ + FROM timetz_tbl + + ORDER BY f1; +(1 row) + +TABLE timetz_local_view; + dat | dat_func | dat_at_local | dat_at_time +----------------+----------------+----------------+---------------- + 00:01:00-07 | 07:01:00+00 | 07:01:00+00 | 07:01:00+00 + 01:00:00-07 | 08:00:00+00 | 08:00:00+00 | 08:00:00+00 + 02:03:00-07 | 09:03:00+00 | 09:03:00+00 | 09:03:00+00 + 08:08:00-04 | 12:08:00+00 | 12:08:00+00 | 12:08:00+00 + 07:07:00-08 | 15:07:00+00 | 15:07:00+00 | 15:07:00+00 + 11:59:00-07 | 18:59:00+00 | 18:59:00+00 | 18:59:00+00 + 12:00:00-07 | 19:00:00+00 | 19:00:00+00 | 19:00:00+00 + 12:01:00-07 | 19:01:00+00 | 19:01:00+00 | 19:01:00+00 + 15:36:39-04 | 19:36:39+00 | 19:36:39+00 | 19:36:39+00 + 15:36:39-05 | 20:36:39+00 | 20:36:39+00 | 20:36:39+00 + 23:59:00-07 | 06:59:00+00 | 06:59:00+00 | 06:59:00+00 + 23:59:59.99-07 | 06:59:59.99+00 | 06:59:59.99+00 | 06:59:59.99+00 +(12 rows) + +DROP VIEW timetz_local_view; +COMMIT; diff --git a/src/test/regress/sql/timestamptz.sql b/src/test/regress/sql/timestamptz.sql index 69b36d0420..cdc57bc160 100644 --- a/src/test/regress/sql/timestamptz.sql +++ b/src/test/regress/sql/timestamptz.sql @@ -611,6 +611,29 @@ SELECT '2014-10-25 22:00:00 UTC'::timestamptz AT TIME ZONE 'MSK'; SELECT '2014-10-25 22:00:01 UTC'::timestamptz AT TIME ZONE 'MSK'; SELECT '2014-10-25 23:00:00 UTC'::timestamptz AT TIME ZONE 'MSK'; +-- +-- Test LOCAL time zone +-- +BEGIN; +SET LOCAL TIME ZONE 'Europe/Paris'; +VALUES (CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL); +VALUES (TIMESTAMP '1978-07-07 19:38' AT LOCAL); +SET LOCAL TIME ZONE 'Australia/Sydney'; +VALUES (CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL); +VALUES (TIMESTAMP '1978-07-07 19:38' AT LOCAL); +SET LOCAL TimeZone TO 'UTC'; +CREATE VIEW timestamp_local_view AS + SELECT CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE) AT LOCAL AS ttz_at_local, + timezone(CAST('1978-07-07 19:38 America/New_York' AS TIMESTAMP WITH TIME ZONE)) AS ttz_func, + TIMESTAMP '1978-07-07 19:38' AT LOCAL AS t_at_local, + timezone(TIMESTAMP '1978-07-07 19:38') AS t_func; +SELECT pg_get_viewdef('timestamp_local_view', true); +\x +TABLE timestamp_local_view; +\x +DROP VIEW timestamp_local_view; +COMMIT; + -- -- Test that AT TIME ZONE isn't misoptimized when using an index (bug #14504) -- diff --git a/src/test/regress/sql/timetz.sql b/src/test/regress/sql/timetz.sql index 93c7bb1428..846006640e 100644 --- a/src/test/regress/sql/timetz.sql +++ b/src/test/regress/sql/timetz.sql @@ -84,3 +84,20 @@ SELECT date_part('microsecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401- SELECT date_part('millisecond', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT date_part('second', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); SELECT date_part('epoch', TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); + +-- +-- AT LOCAL with timetz +-- +BEGIN; +SET LOCAL TimeZone TO 'UTC'; +CREATE VIEW timetz_local_view AS + SELECT f1 AS dat, + timezone(f1) AS dat_func, + f1 AT LOCAL AS dat_at_local, + f1 AT TIME ZONE current_setting('TimeZone') AS dat_at_time + FROM TIMETZ_TBL + ORDER BY f1; +SELECT pg_get_viewdef('timetz_local_view', true); +TABLE timetz_local_view; +DROP VIEW timetz_local_view; +COMMIT;