diff --git a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 index f20791fb29..d52ea2f0a8 100644 --- a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 +++ b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 @@ -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; diff --git a/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 b/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 index f99ee992eb..93267cdeaa 100644 --- a/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 +++ b/contrib/babelfishpg_tsql/antlr/TSqlParser.g4 @@ -4338,6 +4338,7 @@ keyword | DATE_FORMAT | DATENAME | DATEPART + | DATETRUNC | DATE_CORRELATION_OPTIMIZATION | DATE_FORMAT | DAY diff --git a/contrib/babelfishpg_tsql/sql/sys_functions.sql b/contrib/babelfishpg_tsql/sql/sys_functions.sql index 0b8cdb4543..92b73b1511 100644 --- a/contrib/babelfishpg_tsql/sql/sys_functions.sql +++ b/contrib/babelfishpg_tsql/sql/sys_functions.sql @@ -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; diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql index 2965f71f92..b5d8fd90dd 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--3.3.0--3.4.0.sql @@ -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, diff --git a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y index 2e01b52cad..7b8a33a840 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y +++ b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-decl.y @@ -96,7 +96,7 @@ %token 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 diff --git a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y index 5e57be9d3c..b595c5adc1 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y +++ b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y @@ -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"), @@ -4465,6 +4472,7 @@ reserved_keyword: | TSQL_DATE_BUCKET | TSQL_DATENAME | TSQL_DATEPART + | TSQL_DATETRUNC | TSQL_IIF | TSQL_OUT | TSQL_OUTER diff --git a/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h b/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h index 86a2fb3855..3c6e55488f 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h +++ b/contrib/babelfishpg_tsql/src/backend_parser/kwlist.h @@ -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) diff --git a/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l b/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l index fb9d9c7c10..38ea5a6aa6 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l +++ b/contrib/babelfishpg_tsql/src/backend_parser/scan-tsql-rule.l @@ -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: diff --git a/contrib/babelfishpg_tsql/src/special_keywords.c b/contrib/babelfishpg_tsql/src/special_keywords.c index f204025fc6..c608eb4f09 100644 --- a/contrib/babelfishpg_tsql/src/special_keywords.c +++ b/contrib/babelfishpg_tsql/src/special_keywords.c @@ -89,6 +89,7 @@ const char *pg_reserved_keywords_to_be_delimited[] = { "date_bucket", "datename", "datepart", + "datetrunc", "iif", "out", "output", diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out new file mode 100644 index 0000000000..53d3e86cb9 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-cleanup.out @@ -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 diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out new file mode 100644 index 0000000000..51dc0df6e2 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-prepare.out @@ -0,0 +1,233 @@ +-- Test with date datatype +CREATE VIEW DATETRUNC_vu_prepare_v1 AS ( + select + datetrunc(year, cast('2020-04-15' as date)) as dt1, + datetrunc(yy, cast('2020-04-15' as date)) as dt2, + datetrunc(yyyy, cast('2020-04-15' as date)) as dt3, + datetrunc(quarter, cast('2020-04-15' as date)) as dt4, + datetrunc(qq, cast('2020-04-15' as date)) as dt5, + datetrunc(q, cast('2020-04-15' as date)) as dt6, + datetrunc(month, cast('2020-04-15' as date)) as dt7, + datetrunc(mm, cast('2020-04-15' as date)) as dt8, + datetrunc(m, cast('2020-04-15' as date)) as dt9, + datetrunc(dayofyear, cast('2020-04-15' as date)) as dt10, + datetrunc(dy, cast('2020-04-15' as date)) as dt11, + datetrunc(y, cast('2020-04-15' as date)) as dt12, + datetrunc(day, cast('2020-04-15' as date)) as dt13, + datetrunc(dd, cast('2020-04-15' as date)) as dt14, + datetrunc(d, cast('2020-04-15' as date)) as dt15, + datetrunc(week, cast('2020-04-15' as date)) as dt16, + datetrunc(wk, cast('2020-04-15' as date)) as dt17, + datetrunc(ww, cast('2020-04-15' as date)) as dt18, + datetrunc(iso_week, cast('2020-04-15' as date)) as dt19, + datetrunc(isowk, cast('2020-04-15' as date)) as dt20, + datetrunc(isoww, cast('2020-04-15' as date)) as dt21 + ); +GO + +-- Test with time datatype +CREATE VIEW DATETRUNC_vu_prepare_v2 AS ( + select + datetrunc(hour, cast('12:32:45.5647311' as time)) as dt1, + datetrunc(hh, cast('12:32:45.5647311' as time)) as dt2, + datetrunc(minute, cast('12:32:45.5647311' as time)) as dt3, + datetrunc(mi, cast('12:32:45.5647311' as time)) as dt4, + datetrunc(n, cast('12:32:45.5647311' as time)) as dt5, + datetrunc(second, cast('12:32:45.5647311' as time)) as dt6, + datetrunc(ss, cast('12:32:45.5647311' as time)) as dt7, + datetrunc(s, cast('12:32:45.5647311' as time)) as dt8, + datetrunc(millisecond, cast('12:32:45.5647311' as time)) as dt9, + datetrunc(ms, cast('12:32:45.5647311' as time)) as dt10, + datetrunc(microsecond, cast('12:32:45.5647311' as time)) as dt11, + datetrunc(mcs, cast('12:32:45.5647311' as time)) as dt12 + ); +GO + + +-- Test with datetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v3 AS ( + select + datetrunc(year, cast('2004-06-17 09:32:42.566' as datetime)) as dt1, + datetrunc(quarter, cast('2004-06-17 09:32:42.566' as datetime)) as dt2, + datetrunc(month, cast('2004-06-17 09:32:42.566' as datetime)) as dt3, + datetrunc(dayofyear, cast('2004-06-17 09:32:42.566' as datetime)) as dt4, + datetrunc(day, cast('2004-06-17 09:32:42.566' as datetime)) as dt5, + datetrunc(week, cast('2004-06-17 09:32:42.566' as datetime)) as dt6, + datetrunc(hour, cast('2004-06-17 09:32:42.566' as datetime)) as dt7, + datetrunc(minute, cast('2004-06-17 09:32:42.566' as datetime)) as dt8, + datetrunc(second, cast('2004-06-17 09:32:42.566' as datetime)) as dt9, + datetrunc(millisecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt10 + ); +GO +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''datetime''. +CREATE VIEW DATETRUNC_vu_prepare_v4 AS ( + select + datetrunc(microsecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt1 +); +GO + +-- Test with smalldatetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v5 AS ( + select + datetrunc(year, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(quarter, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2, + datetrunc(month, cast('2004-08-14 22:34:20' as smalldatetime)) as dt3, + datetrunc(dayofyear, cast('2004-08-14 22:34:20' as smalldatetime)) as dt4, + datetrunc(day, cast('2004-08-14 22:34:20' as smalldatetime)) as dt5, + datetrunc(week, cast('2004-08-14 22:34:20' as smalldatetime)) as dt6, + datetrunc(hour, cast('2004-08-14 22:34:20' as smalldatetime)) as dt7, + datetrunc(minute, cast('2004-08-14 22:34:20' as smalldatetime)) as dt8, + datetrunc(second, cast('2004-08-14 22:34:20' as smalldatetime)) as dt9 + ); +GO + +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''smalldatetime''. +CREATE VIEW DATETRUNC_vu_prepare_v6 AS ( + select + datetrunc(microsecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(millisecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2 +); +GO + +-- Test with datetime2 datatype +CREATE VIEW DATETRUNC_vu_prepare_v7 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt11 + ); +GO + +-- Test with datetimeoffset datatype +CREATE VIEW DATETRUNC_vu_prepare_v8 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893 +10:42' as datetimeoffset)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893 +02:42' as datetimeoffset)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893 +05:42' as datetimeoffset)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893 +13:42' as datetimeoffset)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893 -12:43' as datetimeoffset)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893 +12:22' as datetimeoffset)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893 -10:42' as datetimeoffset)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt11 + ); +GO + +-- Test with expression input that can be converted to datetime2 datatype. +CREATE VIEW DATETRUNC_vu_prepare_v9 AS ( + select + datetrunc(year, '2021-Jan-01') as dt1, + datetrunc(year, '2021/Jan/01') as dt2, + datetrunc(year, '2021-1-1') as dt3, + datetrunc(year, '20210101') as dt4, + datetrunc(hour, cast('2020-01-01' as varchar)) as dt5, + datetrunc(minute, cast('1980-09-08' as char)) as dt6, + datetrunc(day, '12:32:42') as dt7, + datetrunc(day, '12:32:42.46378') as dt8, + datetrunc(week, '1990-09-09 12:32:09.546') as dt9, + datetrunc(week, '1990-09-09 12:32:09') as dt10, + datetrunc(week, '1990-09-09 12:32:09.546788') as dt11 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale +-- babelfish will always give answer that will include fractional seconds till 7 digits. +CREATE VIEW DATETRUNC_vu_prepare_v10 AS ( + select + datetrunc(hour, cast('12:32:43.4635' as time(3))) dt1, + datetrunc(month, cast('2020-12-23 20:20:20.2222' as datetime2(2))) as dt2, + datetrunc(week, cast('1989-09-23 05:36:43.2930 +12:37' as datetimeoffset(5))) as dt3, + datetrunc(minute, cast('2027-12-13 10:13:20.12236' as datetime2(4))) as dt4, + datetrunc(year, cast('2027-12-13 10:13:20.537478' as datetimeoffset(6))) as dt5 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale which is less then the specified datepart milliseocond, microsecond. +-- Babelfish always give answer to these with fractional seconds till 7 digits, babelfish do not throw an error similar to sql server in this case. +CREATE VIEW DATETRUNC_vu_prepare_v11 AS ( + select + datetrunc(millisecond, cast('2002-01-01 12:33:43.435354' as datetime2(2))) as dt1, + datetrunc(millisecond, cast('2020-01-01 12:33:32.4324' as datetimeoffset(1))) as dt2, + datetrunc(millisecond, cast('12:23:43.464774' as time(0))) as dt3, + datetrunc(microsecond, cast('2002-01-01 12:33:43.435354' as datetime2(5))) as dt4, + datetrunc(microsecond, cast('2020-01-01 12:33:32.437724' as datetimeoffset(4))) as dt5 + ); +GO + + +-- Procedures +-- Test with upper/lower limit of date/time. +CREATE PROCEDURE BABEL_3953_vu_prepare_p1 as ( + SELECT + datetrunc(month, cast('0001-01-01' as date)) as dt1, + datetrunc(month, cast('9999-12-31' as date)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p2 as ( + SELECT + datetrunc(month, cast('1753-01-01 00:00:00 ' as datetime)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.997' as datetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p3 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00' as datetime2)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999999' as datetime2)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p4 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00 -14:00' as datetimeoffset)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999 +14:00' as datetimeoffset)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p5 as ( + SELECT + datetrunc(month, cast('1900-01-01 00:00:00' as smalldatetime)) as dt1, + datetrunc(day, cast('2007-06-05 23:59:59' as smalldatetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p6 as ( + SELECT + datetrunc(hour, cast('00:00:00.0000000' as time)) as dt1, + datetrunc(second, cast('23:59:59.999999' as time)) as dt2 + ); +GO + + +-- functions +CREATE FUNCTION BABEL_3953_vu_prepare_f1() +RETURNS DATETIME2 AS +BEGIN +RETURN (SELECT datetrunc(iso_week, cast('2012-01-23 12:32:23.324' as datetime2))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f2() +RETURNS time AS +BEGIN +RETURN (select datetrunc(second, cast('12:32:53.23' as time))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f3() +RETURNS date AS +BEGIN +RETURN (select datetrunc(week, cast('2001-11-14' as date))); +END +GO diff --git a/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out new file mode 100644 index 0000000000..4c15424174 --- /dev/null +++ b/test/JDBC/expected/BABEL-3953-datetrunc-vu-verify.out @@ -0,0 +1,561 @@ +SELECT * FROM DATETRUNC_vu_prepare_v1 +GO +~~START~~ +date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date#!#date +2020-01-01#!#2020-01-01#!#2020-01-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-01#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-15#!#2020-04-12#!#2020-04-12#!#2020-04-12#!#2020-04-13#!#2020-04-13#!#2020-04-13 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v2 +GO +~~START~~ +time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time#!#time +12:00:00.0000000#!#12:00:00.0000000#!#12:32:00.0000000#!#12:32:00.0000000#!#12:32:00.0000000#!#12:32:45.0000000#!#12:32:45.0000000#!#12:32:45.0000000#!#12:32:45.5640000#!#12:32:45.5640000#!#12:32:45.5647310#!#12:32:45.5647310 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v3 +GO +~~START~~ +datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime#!#datetime +2004-01-01 00:00:00.0#!#2004-04-01 00:00:00.0#!#2004-06-01 00:00:00.0#!#2004-06-17 00:00:00.0#!#2004-06-17 00:00:00.0#!#2004-06-13 00:00:00.0#!#2004-06-17 09:00:00.0#!#2004-06-17 09:32:00.0#!#2004-06-17 09:32:42.0#!#2004-06-17 09:32:42.567 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v4 +GO +~~START~~ +datetime +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart 'microsecond' is not supported by date function datetrunc for data type 'datetime'.)~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v5 +GO +~~START~~ +smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime#!#smalldatetime +2004-01-01 00:00:00.0#!#2004-07-01 00:00:00.0#!#2004-08-01 00:00:00.0#!#2004-08-14 00:00:00.0#!#2004-08-14 00:00:00.0#!#2004-08-08 00:00:00.0#!#2004-08-14 22:00:00.0#!#2004-08-14 22:34:00.0#!#2004-08-14 22:34:00.0 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v6 +GO +~~START~~ +smalldatetime#!#smalldatetime +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: The datepart 'microsecond' is not supported by date function datetrunc for data type 'smalldatetime'.)~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v7 +GO +~~START~~ +datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2 +2015-01-01 00:00:00.0000000#!#2015-10-01 00:00:00.0000000#!#2015-11-01 00:00:00.0000000#!#2015-11-30 00:00:00.0000000#!#2015-11-30 00:00:00.0000000#!#2015-11-29 00:00:00.0000000#!#2015-11-30 09:00:00.0000000#!#2015-11-30 09:34:00.0000000#!#2015-11-30 09:34:56.0000000#!#2015-11-30 09:34:56.6570000#!#2015-11-30 09:34:56.6574890 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v8 +GO +~~START~~ +datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset#!#datetimeoffset +2015-01-01 00:00:00.0000000 +12:42#!#2015-10-01 00:00:00.0000000 +10:42#!#2015-11-01 00:00:00.0000000 +02:42#!#2015-11-30 00:00:00.0000000 +05:42#!#2015-11-30 00:00:00.0000000 +12:42#!#2015-11-29 00:00:00.0000000 +13:42#!#2015-11-30 09:00:00.0000000 +12:42#!#2015-11-30 09:34:00.0000000 -12:43#!#2015-11-30 09:34:56.0000000 +12:22#!#2015-11-30 09:34:56.6570000 -10:42#!#2015-11-30 09:34:56.6574890 +12:42 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v9 +GO +~~START~~ +datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2#!#datetime2 +2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2021-01-01 00:00:00.0000000#!#2020-01-01 00:00:00.0000000#!#1980-09-08 00:00:00.0000000#!#1900-01-01 00:00:00.0000000#!#1900-01-01 00:00:00.0000000#!#1990-09-09 00:00:00.0000000#!#1990-09-09 00:00:00.0000000#!#1990-09-09 00:00:00.0000000 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v10 +GO +~~START~~ +time#!#datetime2#!#datetimeoffset#!#datetime2#!#datetimeoffset +12:00:00.0000000#!#2020-12-01 00:00:00.0000000#!#1989-09-17 00:00:00.0000000 +12:37#!#2027-12-13 10:13:00.0000000#!#2027-01-01 00:00:00.0000000 +00:00 +~~END~~ + + +SELECT * FROM DATETRUNC_vu_prepare_v11 +GO +~~START~~ +datetime2#!#datetimeoffset#!#time#!#datetime2#!#datetimeoffset +2002-01-01 12:33:43.4400000#!#2020-01-01 12:33:32.4000000 +00:00#!#12:23:43.0000000#!#2002-01-01 12:33:43.4353500#!#2020-01-01 12:33:32.4377000 +00:00 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p1 +GO +~~START~~ +date#!#date +0001-01-01#!#9999-12-01 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p2 +GO +~~START~~ +datetime#!#datetime +1753-01-01 00:00:00.0#!#9999-12-01 00:00:00.0 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p3 +GO +~~START~~ +datetime2#!#datetime2 +0001-01-01 00:00:00.0000000#!#9999-12-01 00:00:00.0000000 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p4 +GO +~~START~~ +datetimeoffset#!#datetimeoffset +0001-01-01 00:00:00.0000000 -14:00#!#9999-12-01 00:00:00.0000000 +14:00 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p5 +GO +~~START~~ +smalldatetime#!#smalldatetime +1900-01-01 00:00:00.0#!#2007-06-06 00:00:00.0 +~~END~~ + + +EXEC BABEL_3953_vu_prepare_p6 +GO +~~START~~ +time#!#time +00:00:00.0000000#!#23:59:59.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f1() +GO +~~START~~ +datetime2 +2012-01-23 00:00:00.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f2() +GO +~~START~~ +time +12:32:53.0000000 +~~END~~ + + +SELECT BABEL_3953_vu_prepare_f3() +GO +~~START~~ +date +2001-11-11 +~~END~~ + + +select datetrunc(null, CAST('2020-01-01' as date)) as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc(null, null) as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc(null, 'NULL') as dt1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near "null")~~ + +select datetrunc('NULL', null) as dt1 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'NULL' is not a recognized datetrunc option.)~~ + +select datetrunc('NULL', 'NULL') as dt1 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'NULL' is not a recognized datetrunc option.)~~ + +select datetrunc('year',CAST('2020-01-01' as date)) +go +~~START~~ +date +2020-01-01 +~~END~~ + +select datetrunc(year, null) as dt3 +GO +~~START~~ +datetime2 + +~~END~~ + +select datetrunc(years, null) as dt4 +GO +~~START~~ +datetime2 +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'years' is not a recognized datetrunc option.)~~ + +select datetrunc(nanosecond ,null) as dt5 +GO +~~START~~ +datetime2 + +~~END~~ + +SELECT datetrunc(nanosecond, 2020) +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Argument data type 'integer' is invalid for argument 2 of datetrunc function.)~~ + +select datetrunc(invalid_datepart, 2020) +GO +~~START~~ +int +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'invalid_datepart' is not a recognized datetrunc option.)~~ + +select datetrunc(hour, 2020.0) +GO +~~START~~ +numeric +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Argument data type 'numeric' is invalid for argument 2 of datetrunc function.)~~ + + +-- postgres support 6 digits of fractional time-scale so the bbf output will differ +-- in the last fractional second digit from t-sql. bbf- 2021-12-08 11:30:15.1234570 +-- tsql- 2021-12-08 11:30:15.1234560 +DECLARE @d datetime2 = '2021-12-08 11:30:15.1234567'; +SELECT 'Microsecond', DATETRUNC(microsecond, @d); +Go +~~START~~ +varchar#!#datetime2 +Microsecond#!#2021-12-08 11:30:15.1234570 +~~END~~ + + +DECLARE @test_date date; +SET @test_date = '1998-09-12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +date +1998-09-06 +~~END~~ + + +DECLARE @test_date datetime; +SET @test_date = '2010-09-12 12:23:12.564'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetime +2010-09-12 00:00:00.0 +~~END~~ + + +DECLARE @test_date datetime2; +SET @test_date = '2010-09-12 12:23:12.56443'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetime2 +2010-09-12 00:00:00.0000000 +~~END~~ + + +DECLARE @test_date smalldatetime; +SET @test_date = '2010-09-12 12:23:12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +smalldatetime +2010-09-12 00:00:00.0 +~~END~~ + + +DECLARE @test_date datetimeoffset; +SET @test_date = '2010-09-12 12:23:12.56443 +10:12'; +SELECT datetrunc(week, @test_date); +GO +~~START~~ +datetimeoffset +2010-09-12 00:00:00.0000000 +10:12 +~~END~~ + + +DECLARE @test_date time; +SET @test_date = '12:23:12.56443'; +SELECT datetrunc(hour, @test_date); +GO +~~START~~ +time +12:00:00.0000000 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23' as datetime))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetime +2020-01-09 00:00:00.0 +~~END~~ + +~~START~~ +datetime +2020-01-05 00:00:00.0 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a date) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09' as date))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +date +2020-01-09 +~~END~~ + +~~START~~ +date +2020-01-05 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime2) +insert into dtrunc (a) values(datetrunc(day, '2020-01-09 12:32:23.23')) +Select * from dtrunc +Select datetrunc(day, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetime2 +2020-01-09 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-01-09 00:00:00.0000000 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetimeoffset) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23 -10:23' as datetimeoffset))) +Select * from dtrunc +Select datetrunc(month, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +datetimeoffset +2020-01-09 00:00:00.0000000 -10:23 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-01 00:00:00.0000000 -10:23 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a smalldatetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23' as smalldatetime))) +Select * from dtrunc +Select datetrunc(hour, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a time) +insert into dtrunc (a) values(datetrunc(minute, CAST('12:32:23.23' as time))) +Select * from dtrunc +Select datetrunc(second, a) from dtrunc +GO +~~ROW COUNT: 1~~ + +~~START~~ +time +12:32:00.0000000 +~~END~~ + +~~START~~ +time +12:32:00.0000000 +~~END~~ + + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +GO +~~START~~ +datetime2 +2020-09-07 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-09-07 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +GO +~~START~~ +datetime2 +2020-08-10 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-08-10 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 2 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +GO +~~START~~ +datetime +2020-01-06 00:00:00.0 +~~END~~ + +~~START~~ +datetime +2020-01-07 00:00:00.0 +~~END~~ + + +SET DATEFIRST 3 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12' as date)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12' as date)) +GO +~~START~~ +date +2020-01-06 +~~END~~ + +~~START~~ +date +2020-01-08 +~~END~~ + + +SET DATEFIRST 4 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as smalldatetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as smalldatetime)) +GO +~~START~~ +smalldatetime +2020-01-06 00:00:00.0 +~~END~~ + +~~START~~ +smalldatetime +2020-01-09 00:00:00.0 +~~END~~ + + +SET DATEFIRST 5 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as datetime2)) +GO +~~START~~ +datetime2 +2020-01-06 00:00:00.0000000 +~~END~~ + +~~START~~ +datetime2 +2020-01-10 00:00:00.0000000 +~~END~~ + + +SET DATEFIRST 6 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO +~~START~~ +datetimeoffset +2020-01-06 00:00:00.0000000 +12:32 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-11 00:00:00.0000000 -09:43 +~~END~~ + + +SET DATEFIRST 7 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO +~~START~~ +datetimeoffset +2020-01-06 00:00:00.0000000 +12:32 +~~END~~ + +~~START~~ +datetimeoffset +2020-01-12 00:00:00.0000000 -09:43 +~~END~~ + diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql new file mode 100644 index 0000000000..53d3e86cb9 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-cleanup.sql @@ -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 diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql new file mode 100644 index 0000000000..51dc0df6e2 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-prepare.sql @@ -0,0 +1,233 @@ +-- Test with date datatype +CREATE VIEW DATETRUNC_vu_prepare_v1 AS ( + select + datetrunc(year, cast('2020-04-15' as date)) as dt1, + datetrunc(yy, cast('2020-04-15' as date)) as dt2, + datetrunc(yyyy, cast('2020-04-15' as date)) as dt3, + datetrunc(quarter, cast('2020-04-15' as date)) as dt4, + datetrunc(qq, cast('2020-04-15' as date)) as dt5, + datetrunc(q, cast('2020-04-15' as date)) as dt6, + datetrunc(month, cast('2020-04-15' as date)) as dt7, + datetrunc(mm, cast('2020-04-15' as date)) as dt8, + datetrunc(m, cast('2020-04-15' as date)) as dt9, + datetrunc(dayofyear, cast('2020-04-15' as date)) as dt10, + datetrunc(dy, cast('2020-04-15' as date)) as dt11, + datetrunc(y, cast('2020-04-15' as date)) as dt12, + datetrunc(day, cast('2020-04-15' as date)) as dt13, + datetrunc(dd, cast('2020-04-15' as date)) as dt14, + datetrunc(d, cast('2020-04-15' as date)) as dt15, + datetrunc(week, cast('2020-04-15' as date)) as dt16, + datetrunc(wk, cast('2020-04-15' as date)) as dt17, + datetrunc(ww, cast('2020-04-15' as date)) as dt18, + datetrunc(iso_week, cast('2020-04-15' as date)) as dt19, + datetrunc(isowk, cast('2020-04-15' as date)) as dt20, + datetrunc(isoww, cast('2020-04-15' as date)) as dt21 + ); +GO + +-- Test with time datatype +CREATE VIEW DATETRUNC_vu_prepare_v2 AS ( + select + datetrunc(hour, cast('12:32:45.5647311' as time)) as dt1, + datetrunc(hh, cast('12:32:45.5647311' as time)) as dt2, + datetrunc(minute, cast('12:32:45.5647311' as time)) as dt3, + datetrunc(mi, cast('12:32:45.5647311' as time)) as dt4, + datetrunc(n, cast('12:32:45.5647311' as time)) as dt5, + datetrunc(second, cast('12:32:45.5647311' as time)) as dt6, + datetrunc(ss, cast('12:32:45.5647311' as time)) as dt7, + datetrunc(s, cast('12:32:45.5647311' as time)) as dt8, + datetrunc(millisecond, cast('12:32:45.5647311' as time)) as dt9, + datetrunc(ms, cast('12:32:45.5647311' as time)) as dt10, + datetrunc(microsecond, cast('12:32:45.5647311' as time)) as dt11, + datetrunc(mcs, cast('12:32:45.5647311' as time)) as dt12 + ); +GO + + +-- Test with datetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v3 AS ( + select + datetrunc(year, cast('2004-06-17 09:32:42.566' as datetime)) as dt1, + datetrunc(quarter, cast('2004-06-17 09:32:42.566' as datetime)) as dt2, + datetrunc(month, cast('2004-06-17 09:32:42.566' as datetime)) as dt3, + datetrunc(dayofyear, cast('2004-06-17 09:32:42.566' as datetime)) as dt4, + datetrunc(day, cast('2004-06-17 09:32:42.566' as datetime)) as dt5, + datetrunc(week, cast('2004-06-17 09:32:42.566' as datetime)) as dt6, + datetrunc(hour, cast('2004-06-17 09:32:42.566' as datetime)) as dt7, + datetrunc(minute, cast('2004-06-17 09:32:42.566' as datetime)) as dt8, + datetrunc(second, cast('2004-06-17 09:32:42.566' as datetime)) as dt9, + datetrunc(millisecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt10 + ); +GO +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''datetime''. +CREATE VIEW DATETRUNC_vu_prepare_v4 AS ( + select + datetrunc(microsecond, cast('2004-06-17 09:32:42.566' as datetime)) as dt1 +); +GO + +-- Test with smalldatetime datatype +CREATE VIEW DATETRUNC_vu_prepare_v5 AS ( + select + datetrunc(year, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(quarter, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2, + datetrunc(month, cast('2004-08-14 22:34:20' as smalldatetime)) as dt3, + datetrunc(dayofyear, cast('2004-08-14 22:34:20' as smalldatetime)) as dt4, + datetrunc(day, cast('2004-08-14 22:34:20' as smalldatetime)) as dt5, + datetrunc(week, cast('2004-08-14 22:34:20' as smalldatetime)) as dt6, + datetrunc(hour, cast('2004-08-14 22:34:20' as smalldatetime)) as dt7, + datetrunc(minute, cast('2004-08-14 22:34:20' as smalldatetime)) as dt8, + datetrunc(second, cast('2004-08-14 22:34:20' as smalldatetime)) as dt9 + ); +GO + +-- Should throw exception - 'datepart 'microsecond' is not supported by date function datetrunc for data type ''smalldatetime''. +CREATE VIEW DATETRUNC_vu_prepare_v6 AS ( + select + datetrunc(microsecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt1, + datetrunc(millisecond, cast('2004-08-14 22:34:20' as smalldatetime)) as dt2 +); +GO + +-- Test with datetime2 datatype +CREATE VIEW DATETRUNC_vu_prepare_v7 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893' as datetime2)) as dt11 + ); +GO + +-- Test with datetimeoffset datatype +CREATE VIEW DATETRUNC_vu_prepare_v8 AS ( + select + datetrunc(year, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt1, + datetrunc(quarter, cast('2015-11-30 09:34:56.6574893 +10:42' as datetimeoffset)) as dt2, + datetrunc(month, cast('2015-11-30 09:34:56.6574893 +02:42' as datetimeoffset)) as dt3, + datetrunc(dayofyear, cast('2015-11-30 09:34:56.6574893 +05:42' as datetimeoffset)) as dt4, + datetrunc(day, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt5, + datetrunc(week, cast('2015-11-30 09:34:56.6574893 +13:42' as datetimeoffset)) as dt6, + datetrunc(hour, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt7, + datetrunc(minute, cast('2015-11-30 09:34:56.6574893 -12:43' as datetimeoffset)) as dt8, + datetrunc(second, cast('2015-11-30 09:34:56.6574893 +12:22' as datetimeoffset)) as dt9, + datetrunc(millisecond, cast('2015-11-30 09:34:56.6574893 -10:42' as datetimeoffset)) as dt10, + datetrunc(microsecond, cast('2015-11-30 09:34:56.6574893 +12:42' as datetimeoffset)) as dt11 + ); +GO + +-- Test with expression input that can be converted to datetime2 datatype. +CREATE VIEW DATETRUNC_vu_prepare_v9 AS ( + select + datetrunc(year, '2021-Jan-01') as dt1, + datetrunc(year, '2021/Jan/01') as dt2, + datetrunc(year, '2021-1-1') as dt3, + datetrunc(year, '20210101') as dt4, + datetrunc(hour, cast('2020-01-01' as varchar)) as dt5, + datetrunc(minute, cast('1980-09-08' as char)) as dt6, + datetrunc(day, '12:32:42') as dt7, + datetrunc(day, '12:32:42.46378') as dt8, + datetrunc(week, '1990-09-09 12:32:09.546') as dt9, + datetrunc(week, '1990-09-09 12:32:09') as dt10, + datetrunc(week, '1990-09-09 12:32:09.546788') as dt11 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale +-- babelfish will always give answer that will include fractional seconds till 7 digits. +CREATE VIEW DATETRUNC_vu_prepare_v10 AS ( + select + datetrunc(hour, cast('12:32:43.4635' as time(3))) dt1, + datetrunc(month, cast('2020-12-23 20:20:20.2222' as datetime2(2))) as dt2, + datetrunc(week, cast('1989-09-23 05:36:43.2930 +12:37' as datetimeoffset(5))) as dt3, + datetrunc(minute, cast('2027-12-13 10:13:20.12236' as datetime2(4))) as dt4, + datetrunc(year, cast('2027-12-13 10:13:20.537478' as datetimeoffset(6))) as dt5 + ); +GO + +-- Test when time, datetime2, datetimeoffset casted to a specified fractional scale which is less then the specified datepart milliseocond, microsecond. +-- Babelfish always give answer to these with fractional seconds till 7 digits, babelfish do not throw an error similar to sql server in this case. +CREATE VIEW DATETRUNC_vu_prepare_v11 AS ( + select + datetrunc(millisecond, cast('2002-01-01 12:33:43.435354' as datetime2(2))) as dt1, + datetrunc(millisecond, cast('2020-01-01 12:33:32.4324' as datetimeoffset(1))) as dt2, + datetrunc(millisecond, cast('12:23:43.464774' as time(0))) as dt3, + datetrunc(microsecond, cast('2002-01-01 12:33:43.435354' as datetime2(5))) as dt4, + datetrunc(microsecond, cast('2020-01-01 12:33:32.437724' as datetimeoffset(4))) as dt5 + ); +GO + + +-- Procedures +-- Test with upper/lower limit of date/time. +CREATE PROCEDURE BABEL_3953_vu_prepare_p1 as ( + SELECT + datetrunc(month, cast('0001-01-01' as date)) as dt1, + datetrunc(month, cast('9999-12-31' as date)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p2 as ( + SELECT + datetrunc(month, cast('1753-01-01 00:00:00 ' as datetime)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.997' as datetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p3 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00' as datetime2)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999999' as datetime2)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p4 as ( + SELECT + datetrunc(month, cast('0001-01-01 00:00:00 -14:00' as datetimeoffset)) as dt1, + datetrunc(month, cast('9999-12-31 23:59:59.9999 +14:00' as datetimeoffset)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p5 as ( + SELECT + datetrunc(month, cast('1900-01-01 00:00:00' as smalldatetime)) as dt1, + datetrunc(day, cast('2007-06-05 23:59:59' as smalldatetime)) as dt2 + ); +GO + +CREATE PROCEDURE BABEL_3953_vu_prepare_p6 as ( + SELECT + datetrunc(hour, cast('00:00:00.0000000' as time)) as dt1, + datetrunc(second, cast('23:59:59.999999' as time)) as dt2 + ); +GO + + +-- functions +CREATE FUNCTION BABEL_3953_vu_prepare_f1() +RETURNS DATETIME2 AS +BEGIN +RETURN (SELECT datetrunc(iso_week, cast('2012-01-23 12:32:23.324' as datetime2))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f2() +RETURNS time AS +BEGIN +RETURN (select datetrunc(second, cast('12:32:53.23' as time))); +END +GO + +CREATE FUNCTION BABEL_3953_vu_prepare_f3() +RETURNS date AS +BEGIN +RETURN (select datetrunc(week, cast('2001-11-14' as date))); +END +GO diff --git a/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql new file mode 100644 index 0000000000..ebefb27462 --- /dev/null +++ b/test/JDBC/input/functions/BABEL-3953-datetrunc-vu-verify.sql @@ -0,0 +1,209 @@ +SELECT * FROM DATETRUNC_vu_prepare_v1 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v2 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v3 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v4 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v5 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v6 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v7 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v8 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v9 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v10 +GO + +SELECT * FROM DATETRUNC_vu_prepare_v11 +GO + +EXEC BABEL_3953_vu_prepare_p1 +GO + +EXEC BABEL_3953_vu_prepare_p2 +GO + +EXEC BABEL_3953_vu_prepare_p3 +GO + +EXEC BABEL_3953_vu_prepare_p4 +GO + +EXEC BABEL_3953_vu_prepare_p5 +GO + +EXEC BABEL_3953_vu_prepare_p6 +GO + +SELECT BABEL_3953_vu_prepare_f1() +GO + +SELECT BABEL_3953_vu_prepare_f2() +GO + +SELECT BABEL_3953_vu_prepare_f3() +GO + +select datetrunc(null, CAST('2020-01-01' as date)) as dt1 +GO +select datetrunc(null, null) as dt1 +GO +select datetrunc(null, 'NULL') as dt1 +GO +select datetrunc('NULL', null) as dt1 +GO +select datetrunc('NULL', 'NULL') as dt1 +GO +select datetrunc('year',CAST('2020-01-01' as date)) +go +select datetrunc(year, null) as dt3 +GO +select datetrunc(years, null) as dt4 +GO +select datetrunc(nanosecond ,null) as dt5 +GO +SELECT datetrunc(nanosecond, 2020) +GO +select datetrunc(invalid_datepart, 2020) +GO +select datetrunc(hour, 2020.0) +GO + +-- postgres support 6 digits of fractional time-scale so the bbf output will differ +-- in the last fractional second digit from t-sql. bbf- 2021-12-08 11:30:15.1234570 +-- tsql- 2021-12-08 11:30:15.1234560 +DECLARE @d datetime2 = '2021-12-08 11:30:15.1234567'; +SELECT 'Microsecond', DATETRUNC(microsecond, @d); +Go + +DECLARE @test_date date; +SET @test_date = '1998-09-12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetime; +SET @test_date = '2010-09-12 12:23:12.564'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetime2; +SET @test_date = '2010-09-12 12:23:12.56443'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date smalldatetime; +SET @test_date = '2010-09-12 12:23:12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date datetimeoffset; +SET @test_date = '2010-09-12 12:23:12.56443 +10:12'; +SELECT datetrunc(week, @test_date); +GO + +DECLARE @test_date time; +SET @test_date = '12:23:12.56443'; +SELECT datetrunc(hour, @test_date); +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23' as datetime))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a date) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09' as date))) +Select * from dtrunc +Select datetrunc(week, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetime2) +insert into dtrunc (a) values(datetrunc(day, '2020-01-09 12:32:23.23')) +Select * from dtrunc +Select datetrunc(day, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a datetimeoffset) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23.23 -10:23' as datetimeoffset))) +Select * from dtrunc +Select datetrunc(month, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a smalldatetime) +insert into dtrunc (a) values(datetrunc(day, CAST('2020-01-09 12:32:23' as smalldatetime))) +Select * from dtrunc +Select datetrunc(hour, a) from dtrunc +GO + +DROP TABLE IF EXISTS dtrunc +GO +Create table dtrunc(a time) +insert into dtrunc (a) values(datetrunc(minute, CAST('12:32:23.23' as time))) +Select * from dtrunc +Select datetrunc(second, a) from dtrunc +GO + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-09-13 21:32:32.23' as datetime2)) +GO + +SET DATEFIRST 1 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-08-12 21:32:32.23' as datetime2)) +GO + +SET DATEFIRST 2 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:32:32.23' as datetime)) +GO + +SET DATEFIRST 3 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12' as date)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12' as date)) +GO + +SET DATEFIRST 4 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as smalldatetime)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as smalldatetime)) +GO + +SET DATEFIRST 5 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32' as datetime2)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23' as datetime2)) +GO + +SET DATEFIRST 6 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO + +SET DATEFIRST 7 +SELECT DATETRUNC(ISO_WEEK, CAST('2020-01-12 12:22:32 +12:32' as datetimeoffset)) +SELECT DATETRUNC(WEEK, CAST('2020-01-12 21:23:23 -09:43' as datetimeoffset)) +GO diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 97bcac0f0d..7de0f0759b 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -113,6 +113,7 @@ BABEL-3844 BABEL-3914 BABEL-3938 BABEL-3952 +BABEL-3953-datetrunc BABEL-404 BABEL-405 BABEL-4078 diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 0b8376494e..385115fae4 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -352,7 +352,6 @@ Function sys.datetimeoffset_hash(sys.datetimeoffset) Function sys.datetimeoffset_larger(sys.datetimeoffset,sys.datetimeoffset) Function sys.datetimeoffset_smaller(sys.datetimeoffset,sys.datetimeoffset) Function sys.datetimeoffset_sqlvariant(sys.datetimeoffset) -Function sys.datetimeoffsetscale(sys.datetimeoffset,integer) Function sys.db_id() Function sys.db_id(sys.nvarchar) Function sys.db_name()