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 11, 2021
1 parent 5606bf8 commit 1f8bc01
Show file tree
Hide file tree
Showing 8 changed files with 454 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
23 changes: 23 additions & 0 deletions sql/ts_date_trunc.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
-- 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;

-- utility functions
CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts TIMESTAMP) RETURNS TIMESTAMP
AS '@MODULE_PATHNAME@', 'ts_date_trunc_timestamp' LANGUAGE C IMMUTABLE PARALLEL SAFE STRICT;

CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts TIMESTAMP, origin TIMESTAMP) RETURNS TIMESTAMP
AS '@MODULE_PATHNAME@', 'ts_date_trunc_timestamp' LANGUAGE C IMMUTABLE PARALLEL SAFE STRICT;

CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts TIMESTAMPTZ) RETURNS TIMESTAMPTZ
AS '@MODULE_PATHNAME@', 'ts_date_trunc_timestamptz' LANGUAGE C IMMUTABLE PARALLEL SAFE STRICT;

CREATE OR REPLACE FUNCTION ts_date_trunc(bucket_width INTERVAL, ts TIMESTAMPTZ, origin TIMESTAMPTZ) RETURNS TIMESTAMPTZ
AS '@MODULE_PATHNAME@', 'ts_date_trunc_timestamptz' 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
136 changes: 136 additions & 0 deletions src/ts_date_trunc.c
Original file line number Diff line number Diff line change
@@ -0,0 +1,136 @@
/*
* 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 <utils/fmgrprotos.h>

#include "ts_date_trunc.h"

TS_FUNCTION_INFO_V1(ts_date_trunc);
TS_FUNCTION_INFO_V1(ts_date_trunc_timestamp);
TS_FUNCTION_INFO_V1(ts_date_trunc_timestamptz);

TSDLLEXPORT Datum
ts_date_trunc_timestamp(PG_FUNCTION_ARGS)
{
DateADT result;
Datum interval = PG_GETARG_DATUM(0);
DateADT ts_date = DatumGetDateADT(DirectFunctionCall1(timestamp_date, PG_GETARG_DATUM(1)));

if (PG_NARGS() > 2)
{
DateADT origin = DatumGetDateADT(DirectFunctionCall1(timestamp_date, PG_GETARG_DATUM(2)));
result = DatumGetDateADT(DirectFunctionCall3(ts_date_trunc, interval, DateADTGetDatum(ts_date), DateADTGetDatum(origin)));
}
else
{
result = DatumGetDateADT(DirectFunctionCall2(ts_date_trunc, interval, DateADTGetDatum(ts_date)));
}

return DirectFunctionCall1(date_timestamp, DateADTGetDatum(result));
}

TSDLLEXPORT Datum
ts_date_trunc_timestamptz(PG_FUNCTION_ARGS)
{
DateADT result;
Datum interval = PG_GETARG_DATUM(0);
DateADT ts_date = DatumGetDateADT(DirectFunctionCall1(timestamptz_date, PG_GETARG_DATUM(1)));

if (PG_NARGS() > 2)
{
DateADT origin = DatumGetDateADT(DirectFunctionCall1(timestamptz_date, PG_GETARG_DATUM(2)));
result = DatumGetDateADT(DirectFunctionCall3(ts_date_trunc, interval, DateADTGetDatum(ts_date), DateADTGetDatum(origin)));
}
else
{
result = DatumGetDateADT(DirectFunctionCall2(ts_date_trunc, interval, DateADTGetDatum(ts_date)));
}

return DirectFunctionCall1(date_timestamptz, DateADTGetDatum(result));
}

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

if ((interval->time != 0) || ((interval->month != 0) && (interval->day != 0)))
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("unsupported interval: use either days and weeks, or months and years")));
}

if ((interval->month == 0) && (interval->day == 0))
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("unsupported interval: at least one day expected")));
}

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

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

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

if(interval->month != 0)
{
/* Handle months and years */

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;
}
else
{
/* Handle days and weeks */

if (date < origin_date)
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("`date` < `origin` not supported, choose another `origin`")));
}

delta = date - origin_date;
bucket_number = delta / interval->day;
date = bucket_number * interval->day;
}

PG_RETURN_DATEADT(date);
}
18 changes: 18 additions & 0 deletions src/ts_date_trunc.h
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
/*
* 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);
extern TSDLLEXPORT Datum ts_date_trunc_timestamp(PG_FUNCTION_ARGS);
extern TSDLLEXPORT Datum ts_date_trunc_timestamptz(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)

0 comments on commit 1f8bc01

Please sign in to comment.