Skip to content

Commit

Permalink
Introduce ts_date_trunc function
Browse files Browse the repository at this point in the history
ts_date_trunc() is similar to date_trunc() in PostgreSQL, but
supports intervals like '2 months' or '1 year 6 months'.
  • Loading branch information
Aleksander Alekseev committed May 10, 2021
1 parent bc740a3 commit 6196c8d
Show file tree
Hide file tree
Showing 8 changed files with 260 additions and 1 deletion.
1 change: 1 addition & 0 deletions sql/CMakeLists.txt
Original file line number Diff line number Diff line change
Expand Up @@ -39,6 +39,7 @@ set(SOURCE_FILES
ddl_triggers.sql
bookend.sql
time_bucket.sql
ts_date_trunc.sql
version.sql
size_utils.sql
histogram.sql
Expand Down
10 changes: 10 additions & 0 deletions sql/ts_date_trunc.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
-- This file and its contents are licensed under the Apache License 2.0.
-- Please see the included NOTICE for copyright information and
-- LICENSE-APACHE for a copy of the license.

-- ts_date_trunc() is similar to date_trunc() in PostgreSQL but supports intervals like 'N months'
CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts DATE) RETURNS DATE
AS '@MODULE_PATHNAME@', 'ts_date_trunc' LANGUAGE C IMMUTABLE PARALLEL SAFE STRICT;

CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts DATE, origin DATE) RETURNS DATE
AS '@MODULE_PATHNAME@', 'ts_date_trunc' LANGUAGE C IMMUTABLE PARALLEL SAFE STRICT;
1 change: 1 addition & 0 deletions src/CMakeLists.txt
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,7 @@ set(SOURCES
subspace_store.c
tablespace.c
time_bucket.c
ts_date_trunc.c
time_utils.c
custom_type_cache.c
trigger.c
Expand Down
64 changes: 64 additions & 0 deletions src/ts_date_trunc.c
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
/*
* This file and its contents are licensed under the Apache License 2.0.
* Please see the included NOTICE for copyright information and
* LICENSE-APACHE for a copy of the license.
*/
#include <postgres.h>
#include <utils/date.h>
#include <utils/datetime.h>

#include "ts_date_trunc.h"

TS_FUNCTION_INFO_V1(ts_date_trunc);

TSDLLEXPORT Datum
ts_date_trunc(PG_FUNCTION_ARGS)
{
Interval *interval = PG_GETARG_INTERVAL_P(0);
DateADT date = PG_GETARG_DATEADT(1);
int origin_year = 2000, origin_month = 1, origin_day = 1;
int year, month, day;
int delta, bucket_number;

if (PG_NARGS() > 2)
{
DateADT origin_date = PG_GETARG_DATUM(2);
j2date(origin_date + POSTGRES_EPOCH_JDATE, &origin_year, &origin_month, &origin_day);

if (origin_day != 1)
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("Invalid `origin` day, YYYY-MM-01 expected")));
}
}

if ((interval->time != 0) || (interval->day != 0))
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("only months and years are supported")));
}

if (DATE_NOT_FINITE(date))
PG_RETURN_DATEADT(date);

j2date(date + POSTGRES_EPOCH_JDATE, &year, &month, &day);

if ((year < origin_year) || ((year == origin_year) && (month < origin_month)))
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("`date` < `origin` not supported, choose another `origin`")));
}

delta = (year * 12 + month) - (origin_year * 12 + origin_month);
bucket_number = delta / interval->month;
year = origin_year + (bucket_number * interval->month) / 12;
month =
(((origin_year * 12 + (origin_month - 1)) + (bucket_number * interval->month)) % 12) + 1;
day = 1;

date = date2j(year, month, day) - POSTGRES_EPOCH_JDATE;
PG_RETURN_DATEADT(date);
}
16 changes: 16 additions & 0 deletions src/ts_date_trunc.h
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
/*
* This file and its contents are licensed under the Apache License 2.0.
* Please see the included NOTICE for copyright information and
* LICENSE-APACHE for a copy of the license.
*/
#ifndef TIMESCALEDB_DATE_TRUNC_H
#define TIMESCALEDB_DATE_TRUNC_H

#include <postgres.h>
#include <fmgr.h>

#include "export.h"

extern TSDLLEXPORT Datum ts_date_trunc(PG_FUNCTION_ARGS);

#endif /* TIMESCALEDB_DATE_TRUNC_H */
3 changes: 2 additions & 1 deletion test/expected/extension.out
Original file line number Diff line number Diff line change
Expand Up @@ -75,5 +75,6 @@ WHERE oid IN (
timescaledb_fdw_validator
timescaledb_post_restore
timescaledb_pre_restore
(56 rows)
ts_date_trunc
(57 rows)

114 changes: 114 additions & 0 deletions test/expected/timestamp.out
Original file line number Diff line number Diff line change
Expand Up @@ -1223,6 +1223,120 @@ FROM unnest(ARRAY[
]) AS time;
ERROR: timestamp out of range
\set ON_ERROR_STOP 1
-------------------------------------
--- Test ts_date_trunc function --
-------------------------------------
-- not supported functinality
\set ON_ERROR_STOP 0
SELECT ts_date_trunc('1 hour', '2001-02-03');
ERROR: only months and years are supported
SELECT ts_date_trunc('1 day', '2001-02-03');
ERROR: only months and years are supported
SELECT ts_date_trunc('1 month', '2001-02-03', origin => '2000-01-02');
ERROR: Invalid `origin` day, YYYY-MM-01 expected
SELECT ts_date_trunc('1 month', '2000-01-02', origin => '2001-01-01');
ERROR: `date` < `origin` not supported, choose another `origin`
\set ON_ERROR_STOP 1
-- N month buckets
SELECT d,
ts_date_trunc('1 month', d) as m1,
ts_date_trunc('2 month', d) as m2,
ts_date_trunc('3 month', d) as m3,
ts_date_trunc('4 month', d) as m4,
ts_date_trunc('5 month', d) as m5
FROM generate_series('2020-01-01' :: date, '2020-12-01', '1 month') as ts,
unnest(array[ts :: date]) as d;
d | m1 | m2 | m3 | m4 | m5
------------+------------+------------+------------+------------+------------
01-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020
02-01-2020 | 02-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020
03-01-2020 | 03-01-2020 | 03-01-2020 | 01-01-2020 | 01-01-2020 | 01-01-2020
04-01-2020 | 04-01-2020 | 03-01-2020 | 04-01-2020 | 01-01-2020 | 01-01-2020
05-01-2020 | 05-01-2020 | 05-01-2020 | 04-01-2020 | 05-01-2020 | 01-01-2020
06-01-2020 | 06-01-2020 | 05-01-2020 | 04-01-2020 | 05-01-2020 | 06-01-2020
07-01-2020 | 07-01-2020 | 07-01-2020 | 07-01-2020 | 05-01-2020 | 06-01-2020
08-01-2020 | 08-01-2020 | 07-01-2020 | 07-01-2020 | 05-01-2020 | 06-01-2020
09-01-2020 | 09-01-2020 | 09-01-2020 | 07-01-2020 | 09-01-2020 | 06-01-2020
10-01-2020 | 10-01-2020 | 09-01-2020 | 10-01-2020 | 09-01-2020 | 06-01-2020
11-01-2020 | 11-01-2020 | 11-01-2020 | 10-01-2020 | 09-01-2020 | 11-01-2020
12-01-2020 | 12-01-2020 | 11-01-2020 | 10-01-2020 | 09-01-2020 | 11-01-2020
(12 rows)

-- N month buckets with given `origin`
SELECT d,
ts_date_trunc('1 month', d, origin => '2019-05-01') as m1,
ts_date_trunc('2 month', d, origin => '2019-05-01') as m2,
ts_date_trunc('3 month', d, origin => '2019-05-01') as m3,
ts_date_trunc('4 month', d, origin => '2019-05-01') as m4,
ts_date_trunc('5 month', d, origin => '2019-05-01') as m5
FROM generate_series('2020-01-01' :: date, '2020-12-01', '1 month') as ts,
unnest(array[ts :: date]) as d;
d | m1 | m2 | m3 | m4 | m5
------------+------------+------------+------------+------------+------------
01-01-2020 | 01-01-2019 | 01-01-2019 | 11-01-2019 | 01-01-2019 | 10-01-2019
02-01-2020 | 02-01-2019 | 01-01-2019 | 02-01-2019 | 01-01-2019 | 10-01-2019
03-01-2020 | 03-01-2019 | 03-01-2019 | 02-01-2019 | 01-01-2019 | 03-01-2019
04-01-2020 | 04-01-2019 | 03-01-2019 | 02-01-2019 | 01-01-2019 | 03-01-2019
05-01-2020 | 05-01-2020 | 05-01-2020 | 05-01-2020 | 05-01-2020 | 03-01-2019
06-01-2020 | 06-01-2020 | 05-01-2020 | 05-01-2020 | 05-01-2020 | 03-01-2019
07-01-2020 | 07-01-2020 | 07-01-2020 | 05-01-2020 | 05-01-2020 | 03-01-2019
08-01-2020 | 08-01-2020 | 07-01-2020 | 08-01-2020 | 05-01-2020 | 08-01-2020
09-01-2020 | 09-01-2020 | 09-01-2020 | 08-01-2020 | 09-01-2020 | 08-01-2020
10-01-2020 | 10-01-2020 | 09-01-2020 | 08-01-2020 | 09-01-2020 | 08-01-2020
11-01-2020 | 11-01-2020 | 11-01-2020 | 11-01-2020 | 09-01-2020 | 08-01-2020
12-01-2020 | 12-01-2020 | 11-01-2020 | 11-01-2020 | 09-01-2020 | 08-01-2020
(12 rows)

-- N years / N years, M month buckets
SELECT d,
ts_date_trunc('1 year', d) as y1,
ts_date_trunc('1 year 6 month', d) as y1m6,
ts_date_trunc('2 years', d) as y2,
ts_date_trunc('2 years 6 month', d) as y2m6,
ts_date_trunc('3 years', d) as y3
FROM generate_series('2015-01-01' :: date, '2020-12-01', '6 month') as ts,
unnest(array[ts :: date]) as d;
d | y1 | y1m6 | y2 | y2m6 | y3
------------+------------+------------+------------+------------+------------
01-01-2015 | 01-01-2015 | 01-01-2015 | 01-01-2014 | 01-01-2015 | 01-01-2015
07-01-2015 | 01-01-2015 | 01-01-2015 | 01-01-2014 | 01-01-2015 | 01-01-2015
01-01-2016 | 01-01-2016 | 01-01-2015 | 01-01-2016 | 01-01-2015 | 01-01-2015
07-01-2016 | 01-01-2016 | 07-01-2016 | 01-01-2016 | 01-01-2015 | 01-01-2015
01-01-2017 | 01-01-2017 | 07-01-2016 | 01-01-2016 | 01-01-2015 | 01-01-2015
07-01-2017 | 01-01-2017 | 07-01-2016 | 01-01-2016 | 07-01-2017 | 01-01-2015
01-01-2018 | 01-01-2018 | 01-01-2018 | 01-01-2018 | 07-01-2017 | 01-01-2018
07-01-2018 | 01-01-2018 | 01-01-2018 | 01-01-2018 | 07-01-2017 | 01-01-2018
01-01-2019 | 01-01-2019 | 01-01-2018 | 01-01-2018 | 07-01-2017 | 01-01-2018
07-01-2019 | 01-01-2019 | 07-01-2019 | 01-01-2018 | 07-01-2017 | 01-01-2018
01-01-2020 | 01-01-2020 | 07-01-2019 | 01-01-2020 | 01-01-2020 | 01-01-2018
07-01-2020 | 01-01-2020 | 07-01-2019 | 01-01-2020 | 01-01-2020 | 01-01-2018
(12 rows)

-- N years / N years, M month buckets with given `origin`
SELECT d,
ts_date_trunc('1 year', d, origin => '2000-06-01') as y1,
ts_date_trunc('1 year 6 month', d, origin => '2000-06-01') as y1m6,
ts_date_trunc('2 years', d, origin => '2000-06-01') as y2,
ts_date_trunc('2 years 6 month', d, origin => '2000-06-01') as y2m6,
ts_date_trunc('3 years', d, origin => '2000-06-01') as y3
FROM generate_series('2015-01-01' :: date, '2020-12-01', '6 month') as ts,
unnest(array[ts :: date]) as d;
d | y1 | y1m6 | y2 | y2m6 | y3
------------+------------+------------+------------+------------+------------
01-01-2015 | 06-01-2014 | 12-01-2013 | 06-01-2014 | 12-01-2012 | 06-01-2012
07-01-2015 | 06-01-2015 | 06-01-2015 | 06-01-2014 | 06-01-2015 | 06-01-2015
01-01-2016 | 06-01-2015 | 06-01-2015 | 06-01-2014 | 06-01-2015 | 06-01-2015
07-01-2016 | 06-01-2016 | 06-01-2015 | 06-01-2016 | 06-01-2015 | 06-01-2015
01-01-2017 | 06-01-2016 | 12-01-2016 | 06-01-2016 | 06-01-2015 | 06-01-2015
07-01-2017 | 06-01-2017 | 12-01-2016 | 06-01-2016 | 06-01-2015 | 06-01-2015
01-01-2018 | 06-01-2017 | 12-01-2016 | 06-01-2016 | 12-01-2017 | 06-01-2015
07-01-2018 | 06-01-2018 | 06-01-2018 | 06-01-2018 | 12-01-2017 | 06-01-2018
01-01-2019 | 06-01-2018 | 06-01-2018 | 06-01-2018 | 12-01-2017 | 06-01-2018
07-01-2019 | 06-01-2019 | 06-01-2018 | 06-01-2018 | 12-01-2017 | 06-01-2018
01-01-2020 | 06-01-2019 | 12-01-2019 | 06-01-2018 | 12-01-2017 | 06-01-2018
07-01-2020 | 06-01-2020 | 12-01-2019 | 06-01-2020 | 06-01-2020 | 06-01-2018
(12 rows)

-------------------------------------
--- Test time input functions --
-------------------------------------
Expand Down
52 changes: 52 additions & 0 deletions test/sql/timestamp.sql
Original file line number Diff line number Diff line change
Expand Up @@ -598,6 +598,58 @@ FROM unnest(ARRAY[
]) AS time;
\set ON_ERROR_STOP 1

-------------------------------------
--- Test ts_date_trunc function --
-------------------------------------

-- not supported functinality
\set ON_ERROR_STOP 0
SELECT ts_date_trunc('1 hour', '2001-02-03');
SELECT ts_date_trunc('1 day', '2001-02-03');
SELECT ts_date_trunc('1 month', '2001-02-03', origin => '2000-01-02');
SELECT ts_date_trunc('1 month', '2000-01-02', origin => '2001-01-01');
\set ON_ERROR_STOP 1

-- N month buckets
SELECT d,
ts_date_trunc('1 month', d) as m1,
ts_date_trunc('2 month', d) as m2,
ts_date_trunc('3 month', d) as m3,
ts_date_trunc('4 month', d) as m4,
ts_date_trunc('5 month', d) as m5
FROM generate_series('2020-01-01' :: date, '2020-12-01', '1 month') as ts,
unnest(array[ts :: date]) as d;

-- N month buckets with given `origin`
SELECT d,
ts_date_trunc('1 month', d, origin => '2019-05-01') as m1,
ts_date_trunc('2 month', d, origin => '2019-05-01') as m2,
ts_date_trunc('3 month', d, origin => '2019-05-01') as m3,
ts_date_trunc('4 month', d, origin => '2019-05-01') as m4,
ts_date_trunc('5 month', d, origin => '2019-05-01') as m5
FROM generate_series('2020-01-01' :: date, '2020-12-01', '1 month') as ts,
unnest(array[ts :: date]) as d;

-- N years / N years, M month buckets
SELECT d,
ts_date_trunc('1 year', d) as y1,
ts_date_trunc('1 year 6 month', d) as y1m6,
ts_date_trunc('2 years', d) as y2,
ts_date_trunc('2 years 6 month', d) as y2m6,
ts_date_trunc('3 years', d) as y3
FROM generate_series('2015-01-01' :: date, '2020-12-01', '6 month') as ts,
unnest(array[ts :: date]) as d;

-- N years / N years, M month buckets with given `origin`
SELECT d,
ts_date_trunc('1 year', d, origin => '2000-06-01') as y1,
ts_date_trunc('1 year 6 month', d, origin => '2000-06-01') as y1m6,
ts_date_trunc('2 years', d, origin => '2000-06-01') as y2,
ts_date_trunc('2 years 6 month', d, origin => '2000-06-01') as y2m6,
ts_date_trunc('3 years', d, origin => '2000-06-01') as y3
FROM generate_series('2015-01-01' :: date, '2020-12-01', '6 month') as ts,
unnest(array[ts :: date]) as d;

-------------------------------------
--- Test time input functions --
-------------------------------------
Expand Down

0 comments on commit 6196c8d

Please sign in to comment.