From dc67eb75d6a8794c61f2fca3e38f55ab87c68655 Mon Sep 17 00:00:00 2001 From: Aleksander Alekseev Date: Wed, 1 Sep 2021 13:21:26 +0300 Subject: [PATCH] time_bucket_ng() version with `origin` argument This patch adds a version of time_bucket_ng() with 'origin' argument. It doesn't address any other known issues. E.g. volatility of the function will be changed in another patch. The error messages are going to be improved when the feature gets a little more stable. --- sql/time_bucket_ng.sql | 5 ++-- sql/updates/reverse-dev.sql | 2 +- src/time_bucket.c | 33 ++++++++++++++++++++- src/time_bucket.h | 1 + test/expected/timestamp.out | 59 +++++++++++++++++++++++++++++++++++++ test/sql/timestamp.sql | 19 ++++++++++++ 6 files changed, 115 insertions(+), 4 deletions(-) diff --git a/sql/time_bucket_ng.sql b/sql/time_bucket_ng.sql index a490a28bbdb..d64648dce98 100644 --- a/sql/time_bucket_ng.sql +++ b/sql/time_bucket_ng.sql @@ -47,7 +47,8 @@ CREATE OR REPLACE FUNCTION timescaledb_experimental.time_bucket_ng(bucket_width CREATE OR REPLACE FUNCTION timescaledb_experimental.time_bucket_ng(bucket_width INTERVAL, ts TIMESTAMPTZ, origin TIMESTAMPTZ) RETURNS TIMESTAMPTZ AS '@MODULE_PATHNAME@', 'ts_time_bucket_ng_timestamptz' LANGUAGE C STABLE PARALLEL SAFE STRICT; --- TIMESTAMPTZ version of time_bucket_ng(). +-- TIMESTAMPTZ versions of time_bucket_ng(). CREATE OR REPLACE FUNCTION timescaledb_experimental.time_bucket_ng(bucket_width INTERVAL, ts TIMESTAMPTZ, timezone TEXT) RETURNS TIMESTAMPTZ AS '@MODULE_PATHNAME@', 'ts_time_bucket_ng_timezone' LANGUAGE C STABLE PARALLEL SAFE STRICT; - +CREATE OR REPLACE FUNCTION timescaledb_experimental.time_bucket_ng(bucket_width INTERVAL, ts TIMESTAMPTZ, origin TIMESTAMPTZ, timezone TEXT) RETURNS TIMESTAMPTZ + AS '@MODULE_PATHNAME@', 'ts_time_bucket_ng_timezone_origin' LANGUAGE C STABLE PARALLEL SAFE STRICT; diff --git a/sql/updates/reverse-dev.sql b/sql/updates/reverse-dev.sql index 0bcdc4e0f48..805650befae 100644 --- a/sql/updates/reverse-dev.sql +++ b/sql/updates/reverse-dev.sql @@ -1,2 +1,2 @@ DROP FUNCTION IF EXISTS timescaledb_experimental.time_bucket_ng(bucket_width INTERVAL, ts TIMESTAMPTZ, timezone TEXT); - +DROP FUNCTION IF EXISTS timescaledb_experimental.time_bucket_ng(bucket_width INTERVAL, ts TIMESTAMPTZ, origin TIMESTAMPTZ, timezone TEXT); diff --git a/src/time_bucket.c b/src/time_bucket.c index b60ed334f52..83b0a034bbb 100644 --- a/src/time_bucket.c +++ b/src/time_bucket.c @@ -415,7 +415,9 @@ ts_time_bucket_ng_date(PG_FUNCTION_ARGS) { ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), - errmsg("origin must be the first day of the month"))); + errmsg("origin must be the first day of the month"), + errhint("When using timestamptz-version of the function, 'origin' is " + "converted to provided 'timezone'."))); } if (DATE_NOT_FINITE(date)) @@ -487,3 +489,32 @@ ts_time_bucket_ng_timezone(PG_FUNCTION_ARGS) PG_RETURN_DATUM(DirectFunctionCall2(timestamp_zone, tzname, TimestampGetDatum(result))); } + +TS_FUNCTION_INFO_V1(ts_time_bucket_ng_timezone_origin); +TSDLLEXPORT Datum +ts_time_bucket_ng_timezone_origin(PG_FUNCTION_ARGS) +{ + Timestamp result; + Datum timestamp, origin; + Datum interval = PG_GETARG_DATUM(0); + Datum timestamptz = PG_GETARG_DATUM(1); + Datum origintz = PG_GETARG_DATUM(2); + Datum tzname = PG_GETARG_DATUM(3); + + /* + * Convert 'origin' to TIMESTAMP at given 'tzname'. + * The code is equal to 'origin AT TIME ZONE tzname'. + */ + origin = DirectFunctionCall2(timestamptz_zone, tzname, origintz); + + /* Same for 'timestamptz' */ + timestamp = DirectFunctionCall2(timestamptz_zone, tzname, timestamptz); + + /* Then treat resulting 'timestamp' and 'origin' as a regular ones */ + result = DatumGetTimestamp( + DirectFunctionCall3(ts_time_bucket_ng_timestamp, interval, timestamp, origin)); + if (TIMESTAMP_NOT_FINITE(result)) + PG_RETURN_TIMESTAMP(result); + + PG_RETURN_DATUM(DirectFunctionCall2(timestamp_zone, tzname, TimestampGetDatum(result))); +} diff --git a/src/time_bucket.h b/src/time_bucket.h index ba5b6635aef..f3637d389a1 100644 --- a/src/time_bucket.h +++ b/src/time_bucket.h @@ -22,5 +22,6 @@ extern TSDLLEXPORT Datum ts_time_bucket_ng_date(PG_FUNCTION_ARGS); extern TSDLLEXPORT Datum ts_time_bucket_ng_timestamp(PG_FUNCTION_ARGS); extern TSDLLEXPORT Datum ts_time_bucket_ng_timestamptz(PG_FUNCTION_ARGS); extern TSDLLEXPORT Datum ts_time_bucket_ng_timezone(PG_FUNCTION_ARGS); +extern TSDLLEXPORT Datum ts_time_bucket_ng_timezone_origin(PG_FUNCTION_ARGS); #endif /* TIMESCALEDB_TIME_BUCKET_H */ diff --git a/test/expected/timestamp.out b/test/expected/timestamp.out index d9e6cbdd23e..b378f49d73b 100644 --- a/test/expected/timestamp.out +++ b/test/expected/timestamp.out @@ -1234,6 +1234,7 @@ SELECT timescaledb_experimental.time_bucket_ng('0 days', '2001-02-03' :: date) A ERROR: interval must be at least one day SELECT timescaledb_experimental.time_bucket_ng('1 month', '2001-02-03' :: date, origin => '2000-01-02') AS result; ERROR: origin must be the first day of the month +HINT: When using timestamptz-version of the function, 'origin' is converted to provided 'timezone'. SELECT timescaledb_experimental.time_bucket_ng('1 month', '2000-01-02' :: date, origin => '2001-01-01') AS result; ERROR: origin must be before the given date SELECT timescaledb_experimental.time_bucket_ng('1 day', '2000-01-02' :: date, origin => '2001-01-01') AS result; @@ -1243,6 +1244,10 @@ ERROR: interval can't combine months with minutes or hours -- timestamp is less than the default 'origin' value SELECT timescaledb_experimental.time_bucket_ng('1 day', '1999-01-01 12:34:56 MSK' :: timestamptz, timezone => 'MSK'); ERROR: origin must be before the given date +-- 'origin' in Europe/Moscow timezone is not the first day of the month at given time zone (UTC in this case) +select timescaledb_experimental.time_bucket_ng('1 month', '2021-07-12 12:34:56 Europe/Moscow' :: timestamptz, origin => '2021-06-01 00:00:00 Europe/Moscow' :: timestamptz, timezone => 'UTC'); +ERROR: origin must be the first day of the month +HINT: When using timestamptz-version of the function, 'origin' is converted to provided 'timezone'. \set ON_ERROR_STOP 1 -- wrappers SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-11-22' :: timestamp) AS result; @@ -1312,6 +1317,12 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamptz, or (1 row) +SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; + result +-------- + +(1 row) + -- null interval SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12' :: date) AS result; result @@ -1355,6 +1366,12 @@ SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: ti (1 row) +SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; + result +-------- + +(1 row) + -- null origin SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12' :: date, origin => null) AS result; result @@ -1374,6 +1391,12 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' : (1 row) +SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => null, timezone => 'Europe/Moscow') AS result; + result +-------- + +(1 row) + -- infinity argument SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: date) AS result; result @@ -1417,6 +1440,12 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamp infinity (1 row) +SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; + result +---------- + infinity +(1 row) + -- test for specific code path: hours/minutes/seconds interval and timestamp argument SELECT timescaledb_experimental.time_bucket_ng('12 hours', 'infinity' :: timestamp) AS result; result @@ -1449,6 +1478,12 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' : infinity (1 row) +SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => 'infinity', timezone => 'Europe/Moscow') AS result; + result +---------- + infinity +(1 row) + -- test for specific code path: hours/minutes/seconds interval and timestamp argument SELECT timescaledb_experimental.time_bucket_ng('12 hours', '2021-07-12 12:34:56' :: timestamp, origin => 'infinity') AS result; result @@ -1690,6 +1725,30 @@ ORDER BY tz, bs :: interval; 1 year | UTC | 2021-01-01 00:00:00 +00 (10 rows) +-- Same as above, but with 'origin' +SELECT bs, tz, to_char(ts_out, 'YYYY-MM-DD HH24:MI:SS TZ') as res +FROM unnest(array['Europe/Moscow']) as tz, + unnest(array['12 hours', '1 day', '1 month', '4 months', '1 year']) as bs, + unnest(array['2021-07-12 12:34:56 Europe/Moscow' :: timestamptz]) as ts_in, + unnest(array['2021-06-01 00:00:00 Europe/Moscow' :: timestamptz]) as origin_in, + unnest(array[timescaledb_experimental.time_bucket_ng(bs :: interval, ts_in, origin => origin_in, timezone => tz)]) as ts_out +ORDER BY tz, bs :: interval; + bs | tz | res +----------+---------------+------------------------- + 12 hours | Europe/Moscow | 2021-07-12 09:00:00 +00 + 1 day | Europe/Moscow | 2021-07-11 21:00:00 +00 + 1 month | Europe/Moscow | 2021-06-30 21:00:00 +00 + 4 months | Europe/Moscow | 2021-05-31 21:00:00 +00 + 1 year | Europe/Moscow | 2021-05-31 21:00:00 +00 +(5 rows) + +-- Overwritten origin allows to work with dates earlier than the default origin +SELECT to_char(timescaledb_experimental.time_bucket_ng('1 day', '1999-01-01 12:34:56 MSK' :: timestamptz, origin => '1900-01-01 00:00:00 MSK', timezone => 'MSK'), 'YYYY-MM-DD HH24:MI:SS TZ'); + to_char +------------------------- + 1998-12-31 21:00:00 +00 +(1 row) + -- Restore previously used time zone. ROLLBACK; ------------------------------------- diff --git a/test/sql/timestamp.sql b/test/sql/timestamp.sql index 85086d6de44..7545b449598 100644 --- a/test/sql/timestamp.sql +++ b/test/sql/timestamp.sql @@ -612,6 +612,8 @@ SELECT timescaledb_experimental.time_bucket_ng('1 day', '2000-01-02' :: date, or SELECT timescaledb_experimental.time_bucket_ng('1 month 3 hours', '2021-11-22' :: timestamp) AS result; -- timestamp is less than the default 'origin' value SELECT timescaledb_experimental.time_bucket_ng('1 day', '1999-01-01 12:34:56 MSK' :: timestamptz, timezone => 'MSK'); +-- 'origin' in Europe/Moscow timezone is not the first day of the month at given time zone (UTC in this case) +select timescaledb_experimental.time_bucket_ng('1 month', '2021-07-12 12:34:56 Europe/Moscow' :: timestamptz, origin => '2021-06-01 00:00:00 Europe/Moscow' :: timestamptz, timezone => 'UTC'); \set ON_ERROR_STOP 1 -- wrappers @@ -628,6 +630,7 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamptz, ti SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: date, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamp, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamptz, origin => '2021-06-01') AS result; +SELECT timescaledb_experimental.time_bucket_ng('1 year', null :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; -- null interval SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12' :: date) AS result; @@ -637,11 +640,13 @@ SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: ti SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12' :: date, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: timestamp, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: timestamptz, origin => '2021-06-01') AS result; +SELECT timescaledb_experimental.time_bucket_ng(null, '2021-07-12 12:34:56' :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; -- null origin SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12' :: date, origin => null) AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamp, origin => null) AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => null) AS result; +SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => null, timezone => 'Europe/Moscow') AS result; -- infinity argument SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: date) AS result; @@ -651,6 +656,7 @@ SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamp SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: date, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamp, origin => '2021-06-01') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamptz, origin => '2021-06-01') AS result; +SELECT timescaledb_experimental.time_bucket_ng('1 year', 'infinity' :: timestamptz, origin => '2021-06-01', timezone => 'Europe/Moscow') AS result; -- test for specific code path: hours/minutes/seconds interval and timestamp argument SELECT timescaledb_experimental.time_bucket_ng('12 hours', 'infinity' :: timestamp) AS result; SELECT timescaledb_experimental.time_bucket_ng('12 hours', 'infinity' :: timestamp, origin => '2021-06-01') AS result; @@ -659,6 +665,7 @@ SELECT timescaledb_experimental.time_bucket_ng('12 hours', 'infinity' :: timesta SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12' :: date, origin => 'infinity') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamp, origin => 'infinity') AS result; SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => 'infinity') AS result; +SELECT timescaledb_experimental.time_bucket_ng('1 year', '2021-07-12 12:34:56' :: timestamptz, origin => 'infinity', timezone => 'Europe/Moscow') AS result; -- test for specific code path: hours/minutes/seconds interval and timestamp argument SELECT timescaledb_experimental.time_bucket_ng('12 hours', '2021-07-12 12:34:56' :: timestamp, origin => 'infinity') AS result; @@ -761,6 +768,18 @@ FROM unnest(array['Europe/Moscow', 'UTC']) as tz, unnest(array[timescaledb_experimental.time_bucket_ng(bs :: interval, ts_in, timezone => tz)]) as ts_out ORDER BY tz, bs :: interval; +-- Same as above, but with 'origin' +SELECT bs, tz, to_char(ts_out, 'YYYY-MM-DD HH24:MI:SS TZ') as res +FROM unnest(array['Europe/Moscow']) as tz, + unnest(array['12 hours', '1 day', '1 month', '4 months', '1 year']) as bs, + unnest(array['2021-07-12 12:34:56 Europe/Moscow' :: timestamptz]) as ts_in, + unnest(array['2021-06-01 00:00:00 Europe/Moscow' :: timestamptz]) as origin_in, + unnest(array[timescaledb_experimental.time_bucket_ng(bs :: interval, ts_in, origin => origin_in, timezone => tz)]) as ts_out +ORDER BY tz, bs :: interval; + +-- Overwritten origin allows to work with dates earlier than the default origin +SELECT to_char(timescaledb_experimental.time_bucket_ng('1 day', '1999-01-01 12:34:56 MSK' :: timestamptz, origin => '1900-01-01 00:00:00 MSK', timezone => 'MSK'), 'YYYY-MM-DD HH24:MI:SS TZ'); + -- Restore previously used time zone. ROLLBACK;