Skip to content

Commit

Permalink
support DATETRUNC() function (babelfish-for-postgresql#1846)
Browse files Browse the repository at this point in the history
* support DATETRUNC() function

* test failures

* code refectoring and some jdbc tests

* test failure

* Revert "test failure"

This reverts commit bfcac2e.

* address comments

* address review comments
Signed-off-by: Sandeep Kumawat <[email protected]>

---------

Co-authored-by: Sandeep Kumawat <[email protected]>
  • Loading branch information
2 people authored and ahmed-shameem committed Oct 25, 2023
1 parent 843132c commit a6fc14b
Show file tree
Hide file tree
Showing 17 changed files with 1,582 additions and 2 deletions.
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/antlr/TSqlLexer.g4
Original file line number Diff line number Diff line change
Expand Up @@ -243,6 +243,7 @@ DATEFORMAT: D A T E F O R M A T;
DATE_FORMAT: D A T E UNDERLINE F O R M A T;
DATENAME: D A T E N A M E;
DATEPART: D A T E P A R T;
DATETRUNC: D A T E T R U N C;
DATE_CORRELATION_OPTIMIZATION: D A T E UNDERLINE C O R R E L A T I O N UNDERLINE O P T I M I Z A T I O N;
DAY: D A Y;
DAYS: D A Y S;
Expand Down
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/antlr/TSqlParser.g4
Original file line number Diff line number Diff line change
Expand Up @@ -4338,6 +4338,7 @@ keyword
| DATE_FORMAT
| DATENAME
| DATEPART
| DATETRUNC
| DATE_CORRELATION_OPTIMIZATION
| DATE_FORMAT
| DAY
Expand Down
106 changes: 106 additions & 0 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4386,3 +4386,109 @@ BEGIN
END;
$body$
LANGUAGE plpgsql IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date ANYELEMENT) RETURNS ANYELEMENT AS
$body$
DECLARE
days_offset INT;
v_day INT;
result_date timestamp;
input_expr_timestamp timestamp;
date_arg_datatype regtype;
offset_string PG_CATALOG.TEXT;
datefirst_value INT;
BEGIN
BEGIN
/* perform input validation */
date_arg_datatype := pg_typeof(date);
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
ELSIF date_arg_datatype NOT IN ('date'::regtype, 'time'::regtype, 'sys.datetime'::regtype, 'sys.datetime2'::regtype,
'sys.datetimeoffset'::regtype, 'sys.smalldatetime'::regtype) THEN
RAISE EXCEPTION 'Argument data type ''%'' is invalid for argument 2 of datetrunc function.', date_arg_datatype;
ELSIF datepart IN ('nanosecond', 'tzoffset') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''%''.',datepart, date_arg_datatype;
ELSIF datepart IN ('dow') THEN
RAISE EXCEPTION 'The datepart ''weekday'' is not supported by date function datetrunc for data type ''%''.', date_arg_datatype;
ELSIF date_arg_datatype = 'date'::regtype AND datepart IN ('hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''date''.', datepart;
ELSIF date_arg_datatype = 'datetime'::regtype AND datepart IN ('microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''datetime''.', datepart;
ELSIF date_arg_datatype = 'smalldatetime'::regtype AND datepart IN ('millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''smalldatetime''.', datepart;
ELSIF date_arg_datatype = 'time'::regtype THEN
IF datepart IN ('year', 'quarter', 'month', 'doy', 'day', 'week', 'tsql_week') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''time''.', datepart;
END IF;
-- Limitation in determining if the specified fractional scale (if provided any) for time datatype is
-- insufficient to support provided datepart (millisecond, microsecond) value
ELSIF date_arg_datatype IN ('datetime2'::regtype, 'datetimeoffset'::regtype) THEN
-- Limitation in determining if the specified fractional scale (if provided any) for the above datatype is
-- insufficient to support for provided datepart (millisecond, microsecond) value
END IF;

/* input validation is complete, proceed with result calculation. */
IF date_arg_datatype = 'time'::regtype THEN
RETURN date_trunc(datepart, date);
ELSE
input_expr_timestamp = date::timestamp;
-- preserving offset_string value in the case of datetimeoffset datatype before converting it to timestamps
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
offset_string = RIGHT(date::PG_CATALOG.TEXT, 6);
input_expr_timestamp := LEFT(date::PG_CATALOG.TEXT, -6)::timestamp;
END IF;
CASE
WHEN datepart IN ('year', 'quarter', 'month', 'week', 'hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
result_date := date_trunc(datepart, input_expr_timestamp);
WHEN datepart IN ('doy', 'day') THEN
result_date := date_trunc('day', input_expr_timestamp);
WHEN datepart IN ('tsql_week') THEN
-- sql server datepart 'iso_week' is similar to postgres 'week' datepart
-- handle sql server datepart 'week' here based on the value of set variable 'DATEFIRST'
v_day := EXTRACT(dow from input_expr_timestamp)::INT;
datefirst_value := current_setting('babelfishpg_tsql.datefirst')::INT;
IF v_day = 0 THEN
v_day := 7;
END IF;
result_date := date_trunc('day', input_expr_timestamp);
days_offset := (7 + v_day - datefirst_value)%7;
result_date := result_date - make_interval(days => days_offset);
END CASE;
-- concat offset_string to result_date in case of datetimeoffset before converting it to datetimeoffset datatype.
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
RETURN concat(result_date, ' ', offset_string)::sys.datetimeoffset;
ELSE
RETURN result_date;
END IF;
END IF;
END;
END;
$body$
LANGUAGE plpgsql STABLE;

-- another definition of datetrunc as anyelement can not handle unknown type.
CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date PG_CATALOG.TEXT) RETURNS SYS.DATETIME2 AS
$body$
DECLARE
input_expr_datetime2 sys.datetime2;
BEGIN
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
END IF;
BEGIN
input_expr_datetime2 := cast(date as sys.datetime2);
exception
WHEN others THEN
RAISE USING MESSAGE := 'Conversion failed when converting date and/or time from character string.';
END;
IF input_expr_datetime2 IS NULL THEN
RETURN NULL;
ELSE
-- input string literal is valid, call the datetrunc function with datetime2 datatype.
RETURN sys.DATETRUNC(datepart, input_expr_datetime2);
END IF;
END;
$body$
LANGUAGE plpgsql STABLE;
Original file line number Diff line number Diff line change
Expand Up @@ -757,6 +757,113 @@ $BODY$
LANGUAGE plpgsql
IMMUTABLE;


CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date ANYELEMENT) RETURNS ANYELEMENT AS
$body$
DECLARE
days_offset INT;
v_day INT;
result_date timestamp;
input_expr_timestamp timestamp;
date_arg_datatype regtype;
offset_string PG_CATALOG.TEXT;
datefirst_value INT;
BEGIN
BEGIN
/* perform input validation */
date_arg_datatype := pg_typeof(date);
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
ELSIF date_arg_datatype NOT IN ('date'::regtype, 'time'::regtype, 'sys.datetime'::regtype, 'sys.datetime2'::regtype,
'sys.datetimeoffset'::regtype, 'sys.smalldatetime'::regtype) THEN
RAISE EXCEPTION 'Argument data type ''%'' is invalid for argument 2 of datetrunc function.', date_arg_datatype;
ELSIF datepart IN ('nanosecond', 'tzoffset') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''%''.',datepart, date_arg_datatype;
ELSIF datepart IN ('dow') THEN
RAISE EXCEPTION 'The datepart ''weekday'' is not supported by date function datetrunc for data type ''%''.', date_arg_datatype;
ELSIF date_arg_datatype = 'date'::regtype AND datepart IN ('hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''date''.', datepart;
ELSIF date_arg_datatype = 'datetime'::regtype AND datepart IN ('microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''datetime''.', datepart;
ELSIF date_arg_datatype = 'smalldatetime'::regtype AND datepart IN ('millisecond', 'microsecond') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''smalldatetime''.', datepart;
ELSIF date_arg_datatype = 'time'::regtype THEN
IF datepart IN ('year', 'quarter', 'month', 'doy', 'day', 'week', 'tsql_week') THEN
RAISE EXCEPTION 'The datepart ''%'' is not supported by date function datetrunc for data type ''time''.', datepart;
END IF;
-- Limitation in determining if the specified fractional scale (if provided any) for time datatype is
-- insufficient to support provided datepart (millisecond, microsecond) value
ELSIF date_arg_datatype IN ('datetime2'::regtype, 'datetimeoffset'::regtype) THEN
-- Limitation in determining if the specified fractional scale (if provided any) for the above datatype is
-- insufficient to support for provided datepart (millisecond, microsecond) value
END IF;

/* input validation is complete, proceed with result calculation. */
IF date_arg_datatype = 'time'::regtype THEN
RETURN date_trunc(datepart, date);
ELSE
input_expr_timestamp = date::timestamp;
-- preserving offset_string value in the case of datetimeoffset datatype before converting it to timestamps
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
offset_string = RIGHT(date::PG_CATALOG.TEXT, 6);
input_expr_timestamp := LEFT(date::PG_CATALOG.TEXT, -6)::timestamp;
END IF;
CASE
WHEN datepart IN ('year', 'quarter', 'month', 'week', 'hour', 'minute', 'second', 'millisecond', 'microsecond') THEN
result_date := date_trunc(datepart, input_expr_timestamp);
WHEN datepart IN ('doy', 'day') THEN
result_date := date_trunc('day', input_expr_timestamp);
WHEN datepart IN ('tsql_week') THEN
-- sql server datepart 'iso_week' is similar to postgres 'week' datepart
-- handle sql server datepart 'week' here based on the value of set variable 'DATEFIRST'
v_day := EXTRACT(dow from input_expr_timestamp)::INT;
datefirst_value := current_setting('babelfishpg_tsql.datefirst')::INT;
IF v_day = 0 THEN
v_day := 7;
END IF;
result_date := date_trunc('day', input_expr_timestamp);
days_offset := (7 + v_day - datefirst_value)%7;
result_date := result_date - make_interval(days => days_offset);
END CASE;
-- concat offset_string to result_date in case of datetimeoffset before converting it to datetimeoffset datatype.
IF date_arg_datatype = 'sys.datetimeoffset'::regtype THEN
RETURN concat(result_date, ' ', offset_string)::sys.datetimeoffset;
ELSE
RETURN result_date;
END IF;
END IF;
END;
END;
$body$
LANGUAGE plpgsql STABLE;

-- another definition of datetrunc as anyelement can not handle unknown type.
CREATE OR REPLACE FUNCTION sys.DATETRUNC(IN datepart PG_CATALOG.TEXT, IN date PG_CATALOG.TEXT) RETURNS SYS.DATETIME2 AS
$body$
DECLARE
input_expr_datetime2 sys.datetime2;
BEGIN
IF datepart NOT IN ('year', 'quarter', 'month', 'week', 'tsql_week', 'hour', 'minute', 'second', 'millisecond', 'microsecond',
'doy', 'day', 'nanosecond', 'tzoffset') THEN
RAISE EXCEPTION '''%'' is not a recognized datetrunc option.', datepart;
END IF;
BEGIN
input_expr_datetime2 := cast(date as sys.datetime2);
exception
WHEN others THEN
RAISE USING MESSAGE := 'Conversion failed when converting date and/or time from character string.';
END;
IF input_expr_datetime2 IS NULL THEN
RETURN NULL;
ELSE
-- input string literal is valid, call the datetrunc function with datetime2 datatype.
RETURN sys.DATETRUNC(datepart, input_expr_datetime2);
END IF;
END;
$body$
LANGUAGE plpgsql STABLE;

-- BABELFISH_SCHEMA_PERMISSIONS
CREATE TABLE IF NOT EXISTS sys.babelfish_schema_permissions (
dbid smallint NOT NULL,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -96,7 +96,7 @@

%token <keyword> TSQL_ATAT TSQL_ALLOW_SNAPSHOT_ISOLATION
TSQL_CALLER TSQL_CHOOSE TSQL_CLUSTERED TSQL_COLUMNSTORE TSQL_CONVERT
TSQL_DATENAME TSQL_DATEPART TSQL_DATEDIFF TSQL_DATEDIFF_BIG TSQL_DATE_BUCKET TSQL_DATEADD TSQL_DEFAULT_SCHEMA TSQL_ISNULL
TSQL_DATENAME TSQL_DATEPART TSQL_DATETRUNC TSQL_DATEDIFF TSQL_DATEDIFF_BIG TSQL_DATE_BUCKET TSQL_DATEADD TSQL_DEFAULT_SCHEMA TSQL_ISNULL
TSQL_D TSQL_DAYOFYEAR TSQL_DD TSQL_DW TSQL_DY TSQL_HH TSQL_ISO_WEEK TSQL_ISOWK
TSQL_ISOWW TSQL_LOGIN TSQL_M TSQL_MCS TSQL_MI TSQL_MICROSECOND TSQL_MILLISECOND TSQL_MM TSQL_MS
TSQL_N TSQL_NANOSECOND TSQL_NONCLUSTERED TSQL_NS TSQL_OUTPUT TSQL_OUT TSQL_PARSE TSQL_Q
Expand Down
8 changes: 8 additions & 0 deletions contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y
Original file line number Diff line number Diff line change
Expand Up @@ -1936,6 +1936,13 @@ func_expr_common_subexpr:
COERCE_EXPLICIT_CALL,
@1);
}
| TSQL_DATETRUNC '(' datepart_arg ',' a_expr ')'
{
$$ = (Node *) makeFuncCall(TsqlSystemFuncName2("datetrunc"),
list_make2(makeStringConst($3, @3), $5),
COERCE_EXPLICIT_CALL,
@1);
}
| TSQL_DATENAME '(' datepart_arg ',' a_expr ')'
{
$$ = (Node *) makeFuncCall(TsqlSystemFuncName2("datename"),
Expand Down Expand Up @@ -4465,6 +4472,7 @@ reserved_keyword:
| TSQL_DATE_BUCKET
| TSQL_DATENAME
| TSQL_DATEPART
| TSQL_DATETRUNC
| TSQL_IIF
| TSQL_OUT
| TSQL_OUTER
Expand Down
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/src/backend_parser/kwlist.h
Original file line number Diff line number Diff line change
Expand Up @@ -116,6 +116,7 @@ PG_KEYWORD("datediff", TSQL_DATEDIFF, RESERVED_KEYWORD)
PG_KEYWORD("datediff_big", TSQL_DATEDIFF_BIG, RESERVED_KEYWORD)
PG_KEYWORD("datename", TSQL_DATENAME, RESERVED_KEYWORD)
PG_KEYWORD("datepart", TSQL_DATEPART, RESERVED_KEYWORD)
PG_KEYWORD("datetrunc", TSQL_DATETRUNC, RESERVED_KEYWORD)
PG_KEYWORD("day", DAY_P, UNRESERVED_KEYWORD)
PG_KEYWORD("dayofyear", TSQL_DAYOFYEAR, UNRESERVED_KEYWORD)
PG_KEYWORD("dd", TSQL_DD, UNRESERVED_KEYWORD)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -218,6 +218,7 @@
case TSQL_DATE_BUCKET:
case TSQL_DATENAME:
case TSQL_DATEPART:
case TSQL_DATETRUNC:
case TSQL_D:
case TSQL_DAYOFYEAR:
case TSQL_DD:
Expand Down
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/src/special_keywords.c
Original file line number Diff line number Diff line change
Expand Up @@ -89,6 +89,7 @@ const char *pg_reserved_keywords_to_be_delimited[] = {
"date_bucket",
"datename",
"datepart",
"datetrunc",
"iif",
"out",
"output",
Expand Down
59 changes: 59 additions & 0 deletions test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
DROP VIEW DATETRUNC_vu_prepare_v1
GO

DROP VIEW DATETRUNC_vu_prepare_v2
GO

DROP VIEW DATETRUNC_vu_prepare_v3
GO

DROP VIEW DATETRUNC_vu_prepare_v4
GO

DROP VIEW DATETRUNC_vu_prepare_v5
GO

DROP VIEW DATETRUNC_vu_prepare_v6
GO

DROP VIEW DATETRUNC_vu_prepare_v7
GO

DROP VIEW DATETRUNC_vu_prepare_v8
GO

DROP VIEW DATETRUNC_vu_prepare_v9
GO

DROP VIEW DATETRUNC_vu_prepare_v10
GO

DROP VIEW DATETRUNC_vu_prepare_v11
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p1
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p2
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p3
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p4
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p5
GO

DROP PROCEDURE BABEL_3953_vu_prepare_p6
GO

DROP FUNCTION BABEL_3953_vu_prepare_f1
GO

DROP FUNCTION BABEL_3953_vu_prepare_f2
GO

DROP FUNCTION BABEL_3953_vu_prepare_f3
GO
Loading

0 comments on commit a6fc14b

Please sign in to comment.