From 53a612a514af7424ca1c033fb492662f2520bcad Mon Sep 17 00:00:00 2001 From: Ante Kresic Date: Tue, 9 Jan 2024 14:54:19 +0100 Subject: [PATCH] Handle DST changes in gapfill This change makes gapfill calculate timezone offsets like we do in time_bucket when there is a supplied timezone. Without this, timezones would not align and we get timestamp mismatches which cause double entries for a single bucket. --- .unreleased/fix_6507 | 2 ++ tsl/src/nodes/gapfill/gapfill_exec.c | 30 +++++++++++++++++++++---- tsl/test/shared/expected/gapfill-13.out | 21 ++++++++++++++--- tsl/test/shared/expected/gapfill-14.out | 21 ++++++++++++++--- tsl/test/shared/expected/gapfill-15.out | 21 ++++++++++++++--- tsl/test/shared/expected/gapfill-16.out | 21 ++++++++++++++--- tsl/test/shared/sql/gapfill.sql.in | 5 +++++ 7 files changed, 105 insertions(+), 16 deletions(-) create mode 100644 .unreleased/fix_6507 diff --git a/.unreleased/fix_6507 b/.unreleased/fix_6507 new file mode 100644 index 00000000000..f2c8a88ce38 --- /dev/null +++ b/.unreleased/fix_6507 @@ -0,0 +1,2 @@ +Fixes: #6507 time_bucket_gapfill with timezones doesn't handle daylight savings +Thanks: @JerkoNikolic Thanks for reporting the issue with gapfill and DST diff --git a/tsl/src/nodes/gapfill/gapfill_exec.c b/tsl/src/nodes/gapfill/gapfill_exec.c index 24e2acd1cb4..9c209c97b8e 100644 --- a/tsl/src/nodes/gapfill/gapfill_exec.c +++ b/tsl/src/nodes/gapfill/gapfill_exec.c @@ -656,10 +656,32 @@ gapfill_advance_timestamp(GapFillState *state) * To be consistent with time_bucket we do UTC bucketing unless * a different timezone got explicity passed to the function. */ - next = DirectFunctionCall2(state->have_timezone ? timestamptz_pl_interval : - timestamp_pl_interval, - TimestampTzGetDatum(state->gapfill_start), - IntervalPGetDatum(state->next_offset)); + if (state->have_timezone) + { + bool isnull; + /* TODO: optimize by constifying and caching the datum if possible */ + Datum tzname = gapfill_exec_expr(state, get_timezone_arg(state), &isnull); + Assert(!isnull); + + /* Convert to local timestamp */ + next = DirectFunctionCall2(timestamptz_zone, + tzname, + TimestampTzGetDatum(state->gapfill_start)); + + /* Add interval */ + next = DirectFunctionCall2(timestamp_pl_interval, + next, + IntervalPGetDatum(state->next_offset)); + + /* Convert back to specified timezone */ + next = DirectFunctionCall2(timestamp_zone, tzname, next); + } + else + { + next = DirectFunctionCall2(timestamp_pl_interval, + TimestampTzGetDatum(state->gapfill_start), + IntervalPGetDatum(state->next_offset)); + } state->next_timestamp = DatumGetTimestampTz(next); break; default: diff --git a/tsl/test/shared/expected/gapfill-13.out b/tsl/test/shared/expected/gapfill-13.out index 9d3fd64aab1..a07b634947d 100644 --- a/tsl/test/shared/expected/gapfill-13.out +++ b/tsl/test/shared/expected/gapfill-13.out @@ -3315,9 +3315,9 @@ SELECT time_bucket_gapfill('2 month'::interval, ts, 'UTC', '2000-01-01','2001-01 time_bucket_gapfill Fri Dec 31 16:00:00 1999 PST Tue Feb 29 16:00:00 2000 PST - Sun Apr 30 16:00:00 2000 PDT - Fri Jun 30 16:00:00 2000 PDT - Thu Aug 31 16:00:00 2000 PDT + Sun Apr 30 17:00:00 2000 PDT + Fri Jun 30 17:00:00 2000 PDT + Thu Aug 31 17:00:00 2000 PDT Tue Oct 31 16:00:00 2000 PST Sun Dec 31 16:00:00 2000 PST (7 rows) @@ -3391,6 +3391,21 @@ GROUP BY 1; Fri Jun 30 15:00:00 2023 PDT | (7 rows) +-- Test gapfill respects DST changes when generating timestamps (#6344) +SELECT time_bucket_gapfill('1 month', time, 'awst','2023-01-01', '2023-07-01' ) AS month, sum(value) AS sum +FROM month_timezone +GROUP BY 1; + month | sum +------------------------------+------- + Sat Dec 31 08:00:00 2022 PST | + Tue Jan 31 08:00:00 2023 PST | + Tue Feb 28 08:00:00 2023 PST | 3.123 + Fri Mar 31 09:00:00 2023 PDT | 4.123 + Sun Apr 30 09:00:00 2023 PDT | 5.123 + Wed May 31 09:00:00 2023 PDT | + Fri Jun 30 09:00:00 2023 PDT | +(7 rows) + DROP TABLE month_timezone; -- Test gapfill with additional group pathkeys added for optimization (#6396) CREATE TABLE stocks_real_time ( diff --git a/tsl/test/shared/expected/gapfill-14.out b/tsl/test/shared/expected/gapfill-14.out index 9d3fd64aab1..a07b634947d 100644 --- a/tsl/test/shared/expected/gapfill-14.out +++ b/tsl/test/shared/expected/gapfill-14.out @@ -3315,9 +3315,9 @@ SELECT time_bucket_gapfill('2 month'::interval, ts, 'UTC', '2000-01-01','2001-01 time_bucket_gapfill Fri Dec 31 16:00:00 1999 PST Tue Feb 29 16:00:00 2000 PST - Sun Apr 30 16:00:00 2000 PDT - Fri Jun 30 16:00:00 2000 PDT - Thu Aug 31 16:00:00 2000 PDT + Sun Apr 30 17:00:00 2000 PDT + Fri Jun 30 17:00:00 2000 PDT + Thu Aug 31 17:00:00 2000 PDT Tue Oct 31 16:00:00 2000 PST Sun Dec 31 16:00:00 2000 PST (7 rows) @@ -3391,6 +3391,21 @@ GROUP BY 1; Fri Jun 30 15:00:00 2023 PDT | (7 rows) +-- Test gapfill respects DST changes when generating timestamps (#6344) +SELECT time_bucket_gapfill('1 month', time, 'awst','2023-01-01', '2023-07-01' ) AS month, sum(value) AS sum +FROM month_timezone +GROUP BY 1; + month | sum +------------------------------+------- + Sat Dec 31 08:00:00 2022 PST | + Tue Jan 31 08:00:00 2023 PST | + Tue Feb 28 08:00:00 2023 PST | 3.123 + Fri Mar 31 09:00:00 2023 PDT | 4.123 + Sun Apr 30 09:00:00 2023 PDT | 5.123 + Wed May 31 09:00:00 2023 PDT | + Fri Jun 30 09:00:00 2023 PDT | +(7 rows) + DROP TABLE month_timezone; -- Test gapfill with additional group pathkeys added for optimization (#6396) CREATE TABLE stocks_real_time ( diff --git a/tsl/test/shared/expected/gapfill-15.out b/tsl/test/shared/expected/gapfill-15.out index 9d3fd64aab1..a07b634947d 100644 --- a/tsl/test/shared/expected/gapfill-15.out +++ b/tsl/test/shared/expected/gapfill-15.out @@ -3315,9 +3315,9 @@ SELECT time_bucket_gapfill('2 month'::interval, ts, 'UTC', '2000-01-01','2001-01 time_bucket_gapfill Fri Dec 31 16:00:00 1999 PST Tue Feb 29 16:00:00 2000 PST - Sun Apr 30 16:00:00 2000 PDT - Fri Jun 30 16:00:00 2000 PDT - Thu Aug 31 16:00:00 2000 PDT + Sun Apr 30 17:00:00 2000 PDT + Fri Jun 30 17:00:00 2000 PDT + Thu Aug 31 17:00:00 2000 PDT Tue Oct 31 16:00:00 2000 PST Sun Dec 31 16:00:00 2000 PST (7 rows) @@ -3391,6 +3391,21 @@ GROUP BY 1; Fri Jun 30 15:00:00 2023 PDT | (7 rows) +-- Test gapfill respects DST changes when generating timestamps (#6344) +SELECT time_bucket_gapfill('1 month', time, 'awst','2023-01-01', '2023-07-01' ) AS month, sum(value) AS sum +FROM month_timezone +GROUP BY 1; + month | sum +------------------------------+------- + Sat Dec 31 08:00:00 2022 PST | + Tue Jan 31 08:00:00 2023 PST | + Tue Feb 28 08:00:00 2023 PST | 3.123 + Fri Mar 31 09:00:00 2023 PDT | 4.123 + Sun Apr 30 09:00:00 2023 PDT | 5.123 + Wed May 31 09:00:00 2023 PDT | + Fri Jun 30 09:00:00 2023 PDT | +(7 rows) + DROP TABLE month_timezone; -- Test gapfill with additional group pathkeys added for optimization (#6396) CREATE TABLE stocks_real_time ( diff --git a/tsl/test/shared/expected/gapfill-16.out b/tsl/test/shared/expected/gapfill-16.out index f03606ed10f..15d8bd7ad20 100644 --- a/tsl/test/shared/expected/gapfill-16.out +++ b/tsl/test/shared/expected/gapfill-16.out @@ -3317,9 +3317,9 @@ SELECT time_bucket_gapfill('2 month'::interval, ts, 'UTC', '2000-01-01','2001-01 time_bucket_gapfill Fri Dec 31 16:00:00 1999 PST Tue Feb 29 16:00:00 2000 PST - Sun Apr 30 16:00:00 2000 PDT - Fri Jun 30 16:00:00 2000 PDT - Thu Aug 31 16:00:00 2000 PDT + Sun Apr 30 17:00:00 2000 PDT + Fri Jun 30 17:00:00 2000 PDT + Thu Aug 31 17:00:00 2000 PDT Tue Oct 31 16:00:00 2000 PST Sun Dec 31 16:00:00 2000 PST (7 rows) @@ -3393,6 +3393,21 @@ GROUP BY 1; Fri Jun 30 15:00:00 2023 PDT | (7 rows) +-- Test gapfill respects DST changes when generating timestamps (#6344) +SELECT time_bucket_gapfill('1 month', time, 'awst','2023-01-01', '2023-07-01' ) AS month, sum(value) AS sum +FROM month_timezone +GROUP BY 1; + month | sum +------------------------------+------- + Sat Dec 31 08:00:00 2022 PST | + Tue Jan 31 08:00:00 2023 PST | + Tue Feb 28 08:00:00 2023 PST | 3.123 + Fri Mar 31 09:00:00 2023 PDT | 4.123 + Sun Apr 30 09:00:00 2023 PDT | 5.123 + Wed May 31 09:00:00 2023 PDT | + Fri Jun 30 09:00:00 2023 PDT | +(7 rows) + DROP TABLE month_timezone; -- Test gapfill with additional group pathkeys added for optimization (#6396) CREATE TABLE stocks_real_time ( diff --git a/tsl/test/shared/sql/gapfill.sql.in b/tsl/test/shared/sql/gapfill.sql.in index 3a44b2d3740..b8059c696ac 100644 --- a/tsl/test/shared/sql/gapfill.sql.in +++ b/tsl/test/shared/sql/gapfill.sql.in @@ -1536,6 +1536,11 @@ FROM month_timezone GROUP BY 1; +-- Test gapfill respects DST changes when generating timestamps (#6344) +SELECT time_bucket_gapfill('1 month', time, 'awst','2023-01-01', '2023-07-01' ) AS month, sum(value) AS sum +FROM month_timezone +GROUP BY 1; + DROP TABLE month_timezone; -- Test gapfill with additional group pathkeys added for optimization (#6396)