From 3113bd6c374d664be64b01e2f6d80481f7dd9b06 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Wed, 19 Jul 2023 11:04:02 +0000 Subject: [PATCH 01/27] Casting a DATE literal without time part to TIME datatype fails For time datatype PG considers only date value(ex: '2012-02-23') as bad i/p format. So above testcase is throwing error from engine code time_in() much before coming to TDS side. The current time casting doesn't support i/p having month in text format(ex: '20120-jan-3 2:3') and whitespaces between the time for casting to different formats. However, SQL Server allows casting a date literal string to a TIME datatype when the time component in the string is missing: o/p becomes 00:00:00.0000000. SQL Server also allows whitespaces in between and supports i/p of month in text when casting to time datatype. This commit fixes the issue such that date format with missing time info like above considers as valid input when the dialect is TSQL. Supports month in text format while casting to time datatype. Supports whitespaces between the time. Task: BABEL-1528 Signed-off-by: vasavi suthapalli --- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 17 ++ test/JDBC/expected/babel_datatype.out | 91 ++++++++++ test/JDBC/expected/babel_time-vu-cleanup.out | 11 ++ test/JDBC/expected/babel_time-vu-prepare.out | 21 +++ test/JDBC/expected/babel_time-vu-verify.out | 172 +++++++++++++++++++ test/JDBC/input/babel_datatype.sql | 31 ++++ test/JDBC/input/babel_time-vu-cleanup.sql | 11 ++ test/JDBC/input/babel_time-vu-prepare.sql | 19 ++ test/JDBC/input/babel_time-vu-verify.mix | 69 ++++++++ 9 files changed, 442 insertions(+) create mode 100644 test/JDBC/expected/babel_time-vu-cleanup.out create mode 100644 test/JDBC/expected/babel_time-vu-prepare.out create mode 100644 test/JDBC/expected/babel_time-vu-verify.out create mode 100644 test/JDBC/input/babel_time-vu-cleanup.sql create mode 100644 test/JDBC/input/babel_time-vu-prepare.sql create mode 100644 test/JDBC/input/babel_time-vu-verify.mix diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 9ffe11eefb..67eb9f1b69 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -3,6 +3,7 @@ #include #include #include +#include #include #pragma GCC diagnostic ignored "-Wattributes" @@ -1917,6 +1918,22 @@ class tsqlBuilder : public tsqlCommonMutator /* Re-write session_user to sys.session_user(). */ if (bctx->bif_no_brackets && bctx->SESSION_USER()) rewritten_query_fragment.emplace(std::make_pair(bctx->bif_no_brackets->getStartIndex(), std::make_pair(::getFullText(bctx->SESSION_USER()), "sys.session_user()"))); + + if(bctx->bif_cast_parse() && bctx->bif_cast_parse()->bif && bctx->bif_cast_parse()->bif) + { + auto temp = bctx->bif_cast_parse(); + if(temp->data_type() && (pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0 || + pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "DATE", 4) == 0 || + pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "SMALLDATETIME", 13) == 0)) + { + std::string s(pstrdup(::getFullText(temp->expression()).c_str())); + std::regex pattern("\\s*([-/:.])\\s*"); + std::string result = std::regex_replace(s, pattern, "$1"); + if ( s!= result) + rewritten_query_fragment.emplace(std::make_pair(temp->expression()->start->getStartIndex(), std::make_pair(::getFullText(temp->expression()), result))); + s = (pstrdup(::getFullText(temp->expression()).c_str())); + } + } } /* analyze scalar function call */ diff --git a/test/JDBC/expected/babel_datatype.out b/test/JDBC/expected/babel_datatype.out index 2d9bf5db06..2c41923eed 100644 --- a/test/JDBC/expected/babel_datatype.out +++ b/test/JDBC/expected/babel_datatype.out @@ -648,6 +648,92 @@ smalldatetime 2020-03-15 09:00:00.0 ~~END~~ +select CAST('2020-MarCh-15' AS date); +GO +~~START~~ +date +2020-03-15 +~~END~~ + +select CAST('2020-mar-15 09:00:00+8' AS datetimeoffset); +GO +~~START~~ +datetimeoffset +2020-03-15 09:00:00.0000000 +08:00 +~~END~~ + +select CAST('2020-MAR-15 09:00:00' AS datetime2); +GO +~~START~~ +datetime2 +2020-03-15 09:00:00.0000000 +~~END~~ + +select CAST('2020-MaR-15 09:00:00' AS smalldatetime); +GO +~~START~~ +smalldatetime +2020-03-15 09:00:00.0 +~~END~~ + + +select CAST('2020 - 03 - 15' AS date); +GO +~~START~~ +date +2020-03-15 +~~END~~ + +select CAST('2020 - 03-15 09 : 00 : 00 + 8' AS datetimeoffset); +GO +~~START~~ +datetimeoffset +2020-03-15 09:00:00.0000000 +08:00 +~~END~~ + +select CAST('2020-03 -15 09 : 00 : 00' AS datetime2); +GO +~~START~~ +datetime2 +2020-03-15 09:00:00.0000000 +~~END~~ + +select CAST('2020-03- 15 09 : 00 : 00' AS smalldatetime); +GO +~~START~~ +smalldatetime +2020-03-15 09:00:00.0 +~~END~~ + +select CAST('2020 -MarCh-15 09 : 00: 00+8' AS date); +GO +~~START~~ +date +2020-03-15 +~~END~~ + +select CAST('2020- mar-15 09:00:00+8' AS datetimeoffset); +GO +~~START~~ +datetimeoffset +2020-03-15 09:00:00.0000000 +08:00 +~~END~~ + +select CAST('2020- MAR -15 09 : 00 : 00' AS datetime2); +GO +~~START~~ +datetime2 +2020-03-15 09:00:00.0000000 +~~END~~ + +select CAST('2020 - MaR - 15 09:00:00' AS smalldatetime); +GO +~~START~~ +smalldatetime +2020-03-15 09:00:00.0 +~~END~~ + + -- test the range of date select CAST('0001-01-01' AS date); GO @@ -1550,6 +1636,11 @@ postgres ~~END~~ +DROP TABLE s1.test1; +go + +DROP SCHEMA s1; +GO -- test tinyint data type select CAST(100 AS tinyint); diff --git a/test/JDBC/expected/babel_time-vu-cleanup.out b/test/JDBC/expected/babel_time-vu-cleanup.out new file mode 100644 index 0000000000..c53fe5d40f --- /dev/null +++ b/test/JDBC/expected/babel_time-vu-cleanup.out @@ -0,0 +1,11 @@ +DROP TABLE babel_time_vu_prepare_t1 +GO + +DROP VIEW babel_time_vu_prepare_v1 +GO + +DROP PROCEDURE babel_time_vu_prepare_p1 +GO + +DROP FUNCTION babel_time_vu_prepare_f1 +GO diff --git a/test/JDBC/expected/babel_time-vu-prepare.out b/test/JDBC/expected/babel_time-vu-prepare.out new file mode 100644 index 0000000000..c83a9d5336 --- /dev/null +++ b/test/JDBC/expected/babel_time-vu-prepare.out @@ -0,0 +1,21 @@ +create table babel_time_vu_prepare_t1(a time) +GO + +insert into babel_time_vu_prepare_t1 values ('2012-02-23') +GO +~~ROW COUNT: 1~~ + + +create view babel_time_vu_prepare_v1 as select CAST('2012-02-23' AS time) as val +GO + +create procedure babel_time_vu_prepare_p1 as select CAST('2012-02-23' AS time) as val +GO + +create function babel_time_vu_prepare_f1() +returns time +as +begin + return (select CAST('2012-02-23' AS time) as val) +end +GO diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out new file mode 100644 index 0000000000..dd517efb09 --- /dev/null +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -0,0 +1,172 @@ +-- psql +SELECT CAST('2012-02-23' AS TIME) +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: invalid input syntax for type time: "2012-02-23" + Position: 13 + Server SQLState: 22007)~~ + + +-- tsql +SELECT CAST('2012-02-23' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('12 jan 20 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('2012 - fEb - 23' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(0)) +GO +~~START~~ +time +01:05:06 +~~END~~ + + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +GO +~~START~~ +time +01:05:06.2890000 +~~END~~ + + +-- these particular cases are failing in SQL Server but passing in bbf +SELECT CAST('121200' AS TIME) +GO +~~START~~ +time +12:12:00.0000000 +~~END~~ + + +SELECT CAST('2012- 02- 23 02 : 03 : 00 + 8' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "Jan 2021 01 010506.289")~~ + + +SELECT CAST('Jan-2021-01 121200 -1' AS TIME) +GO +~~START~~ +time +12:12:00.0000000 +~~END~~ + + +select CAST(CAST('2020 - 03 - 15' AS date) AS time); +GO +-~~START~~ +-datetime +-2020-03-15 00:00:00.0 +-~~END~~ + + +-- Negative cases +SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "Jan-2021-01 121200 1-1")~~ + + +SELECT CAST('+02' AS TIME); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "+02")~~ + + +SELECT CAST('20121200' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "20121200")~~ + + +SELECT CAST('2012jan00' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "2012jan00")~~ + + +SELECT CAST('Jan 2021 010506.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "Jan 2021 010506.289")~~ + + +SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: invalid input syntax for type time: "Jan 2021 01 01 05 06 . 289")~~ + + +SELECT CAST('Jan-2021-01 121200 ' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ + + +SELECT * from babel_TIME_vu_prepare_t1 +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT babel_TIME_vu_prepare_f1() +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +exec babel_TIME_vu_prepare_p1 +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT * FROM babel_TIME_vu_prepare_v1 +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + diff --git a/test/JDBC/input/babel_datatype.sql b/test/JDBC/input/babel_datatype.sql index e85d5763ce..60d34e2639 100644 --- a/test/JDBC/input/babel_datatype.sql +++ b/test/JDBC/input/babel_datatype.sql @@ -233,6 +233,32 @@ select CAST('2020-03-15 09:00:00' AS datetime2); GO select CAST('2020-03-15 09:00:00' AS smalldatetime); GO +select CAST('2020-MarCh-15' AS date); +GO +select CAST('2020-mar-15 09:00:00+8' AS datetimeoffset); +GO +select CAST('2020-MAR-15 09:00:00' AS datetime2); +GO +select CAST('2020-MaR-15 09:00:00' AS smalldatetime); +GO + +select CAST('2020 - 03 - 15' AS date); +GO +select CAST('2020 - 03-15 09 : 00 : 00 + 8' AS datetimeoffset); +GO +select CAST('2020-03 -15 09 : 00 : 00' AS datetime2); +GO +select CAST('2020-03- 15 09 : 00 : 00' AS smalldatetime); +GO +select CAST('2020 -MarCh-15 09 : 00: 00+8' AS date); +GO +select CAST('2020- mar-15 09:00:00+8' AS datetimeoffset); +GO +select CAST('2020- MAR -15 09 : 00 : 00' AS datetime2); +GO +select CAST('2020 - MaR - 15 09:00:00' AS smalldatetime); +GO + -- test the range of date select CAST('0001-01-01' AS date); GO @@ -624,6 +650,11 @@ GO SELECT set_config('babelfishpg_tsql.sql_dialect', 'postgres', false); GO +DROP TABLE s1.test1; +go + +DROP SCHEMA s1; +GO -- test tinyint data type select CAST(100 AS tinyint); diff --git a/test/JDBC/input/babel_time-vu-cleanup.sql b/test/JDBC/input/babel_time-vu-cleanup.sql new file mode 100644 index 0000000000..c53fe5d40f --- /dev/null +++ b/test/JDBC/input/babel_time-vu-cleanup.sql @@ -0,0 +1,11 @@ +DROP TABLE babel_time_vu_prepare_t1 +GO + +DROP VIEW babel_time_vu_prepare_v1 +GO + +DROP PROCEDURE babel_time_vu_prepare_p1 +GO + +DROP FUNCTION babel_time_vu_prepare_f1 +GO diff --git a/test/JDBC/input/babel_time-vu-prepare.sql b/test/JDBC/input/babel_time-vu-prepare.sql new file mode 100644 index 0000000000..581eca05e4 --- /dev/null +++ b/test/JDBC/input/babel_time-vu-prepare.sql @@ -0,0 +1,19 @@ +create table babel_time_vu_prepare_t1(a time) +GO + +insert into babel_time_vu_prepare_t1 values ('2012-02-23') +GO + +create view babel_time_vu_prepare_v1 as select CAST('2012-02-23' AS time) as val +GO + +create procedure babel_time_vu_prepare_p1 as select CAST('2012-02-23' AS time) as val +GO + +create function babel_time_vu_prepare_f1() +returns time +as +begin + return (select CAST('2012-02-23' AS time) as val) +end +GO diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix new file mode 100644 index 0000000000..965cf8c61a --- /dev/null +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -0,0 +1,69 @@ +-- psql +SELECT CAST('2012-02-23' AS TIME) +GO + +-- tsql +SELECT CAST('2012-02-23' AS TIME) +GO + +SELECT CAST('12 jan 20 2:3' AS TIME) +GO + +SELECT CAST('2012 - fEb - 23' AS TIME) +GO + +SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(0)) +GO + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +GO + +-- these particular cases are failing in SQL Server but passing in bbf +SELECT CAST('121200' AS TIME) +GO + +SELECT CAST('2012- 02- 23 02 : 03 : 00 + 8' AS TIME) +GO + +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO + +SELECT CAST('Jan-2021-01 121200 -1' AS TIME) +GO + +select CAST(CAST('2020 - 03 - 15' AS date) AS time); +GO + +-- Negative cases +SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) +GO + +SELECT CAST('+02' AS TIME); +GO + +SELECT CAST('20121200' AS TIME) +GO + +SELECT CAST('2012jan00' AS TIME) +GO + +SELECT CAST('Jan 2021 010506.289' AS TIME) +GO + +SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) +GO + +SELECT CAST('Jan-2021-01 121200 ' AS TIME) +GO + +SELECT * from babel_TIME_vu_prepare_t1 +GO + +SELECT babel_TIME_vu_prepare_f1() +GO + +exec babel_TIME_vu_prepare_p1 +GO + +SELECT * FROM babel_TIME_vu_prepare_v1 +GO From 94c338e92d2558f613d2d22073c5f88a3f56d4a0 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Mon, 7 Aug 2023 11:40:51 +0000 Subject: [PATCH 02/27] Added hook and modified the tests --- contrib/babelfishpg_tsql/src/hooks.c | 22 + contrib/babelfishpg_tsql/src/tsqlIface.cpp | 1 - test/JDBC/expected/babel_datatype.out | 85 ---- test/JDBC/expected/babel_time-vu-verify.out | 500 +++++++++++++++++++- test/JDBC/input/babel_datatype.sql | 25 - test/JDBC/input/babel_time-vu-verify.mix | 206 +++++++- 6 files changed, 695 insertions(+), 144 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 8fc889c736..13f867acc5 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -44,6 +44,7 @@ #include "rewrite/rewriteHandler.h" #include "tcop/utility.h" #include "utils/builtins.h" +#include "utils/date.h" #include "utils/fmgroids.h" #include "utils/lsyscache.h" #include "utils/rel.h" @@ -138,6 +139,7 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, const char *queryString, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); +static void pltsql_parse_time_error(int dterr, const char *str, const char *datatype); /***************************************** * Executor Hooks @@ -208,6 +210,7 @@ static table_variable_satisfies_update_hook_type prev_table_variable_satisfies_u static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_vacuum = NULL; static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; +static time_hook_type prev_time_hook = NULL; /***************************************** * Install / Uninstall @@ -352,6 +355,9 @@ InstallExtendedHooks(void) prev_drop_relation_refcnt_hook = drop_relation_refcnt_hook; drop_relation_refcnt_hook = pltsql_drop_relation_refcnt_hook; + + prev_time_hook = time_hook; + time_hook = pltsql_parse_time_error; } void @@ -408,6 +414,7 @@ UninstallExtendedHooks(void) IsToastRelationHook = PrevIsToastRelationHook; IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; + time_hook = prev_time_hook; } /***************************************** @@ -2617,6 +2624,21 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume return (total_digit_count > TDS_NUMERIC_MAX_PRECISION); } +/* + * Throw a common error message while casting to time datatype + */ +void pltsql_parse_time_error(int dterr, const char *str, const char *datatype) +{ + switch (dterr) + { + default: + ereport(ERROR, + (errcode(ERRCODE_INVALID_DATETIME_FORMAT), + errmsg("Conversion failed when converting date and/or time from character string."))); + break; + } +} + /* * Stores argument positions of default values of a PL/tsql function to bbf_function_ext catalog */ diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 67eb9f1b69..234af5ea87 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1931,7 +1931,6 @@ class tsqlBuilder : public tsqlCommonMutator std::string result = std::regex_replace(s, pattern, "$1"); if ( s!= result) rewritten_query_fragment.emplace(std::make_pair(temp->expression()->start->getStartIndex(), std::make_pair(::getFullText(temp->expression()), result))); - s = (pstrdup(::getFullText(temp->expression()).c_str())); } } } diff --git a/test/JDBC/expected/babel_datatype.out b/test/JDBC/expected/babel_datatype.out index 2c41923eed..b458f472d4 100644 --- a/test/JDBC/expected/babel_datatype.out +++ b/test/JDBC/expected/babel_datatype.out @@ -648,91 +648,6 @@ smalldatetime 2020-03-15 09:00:00.0 ~~END~~ -select CAST('2020-MarCh-15' AS date); -GO -~~START~~ -date -2020-03-15 -~~END~~ - -select CAST('2020-mar-15 09:00:00+8' AS datetimeoffset); -GO -~~START~~ -datetimeoffset -2020-03-15 09:00:00.0000000 +08:00 -~~END~~ - -select CAST('2020-MAR-15 09:00:00' AS datetime2); -GO -~~START~~ -datetime2 -2020-03-15 09:00:00.0000000 -~~END~~ - -select CAST('2020-MaR-15 09:00:00' AS smalldatetime); -GO -~~START~~ -smalldatetime -2020-03-15 09:00:00.0 -~~END~~ - - -select CAST('2020 - 03 - 15' AS date); -GO -~~START~~ -date -2020-03-15 -~~END~~ - -select CAST('2020 - 03-15 09 : 00 : 00 + 8' AS datetimeoffset); -GO -~~START~~ -datetimeoffset -2020-03-15 09:00:00.0000000 +08:00 -~~END~~ - -select CAST('2020-03 -15 09 : 00 : 00' AS datetime2); -GO -~~START~~ -datetime2 -2020-03-15 09:00:00.0000000 -~~END~~ - -select CAST('2020-03- 15 09 : 00 : 00' AS smalldatetime); -GO -~~START~~ -smalldatetime -2020-03-15 09:00:00.0 -~~END~~ - -select CAST('2020 -MarCh-15 09 : 00: 00+8' AS date); -GO -~~START~~ -date -2020-03-15 -~~END~~ - -select CAST('2020- mar-15 09:00:00+8' AS datetimeoffset); -GO -~~START~~ -datetimeoffset -2020-03-15 09:00:00.0000000 +08:00 -~~END~~ - -select CAST('2020- MAR -15 09 : 00 : 00' AS datetime2); -GO -~~START~~ -datetime2 -2020-03-15 09:00:00.0000000 -~~END~~ - -select CAST('2020 - MaR - 15 09:00:00' AS smalldatetime); -GO -~~START~~ -smalldatetime -2020-03-15 09:00:00.0 -~~END~~ - -- test the range of date select CAST('0001-01-01' AS date); diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out index dd517efb09..bdef0888ee 100644 --- a/test/JDBC/expected/babel_time-vu-verify.out +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -1,14 +1,16 @@ -- psql +-- behaviour of casting to time in psql SELECT CAST('2012-02-23' AS TIME) GO ~~ERROR (Code: 0)~~ ~~ERROR (Message: ERROR: invalid input syntax for type time: "2012-02-23" - Position: 13 + Position: 53 Server SQLState: 22007)~~ -- tsql +-- when month is given in nymeric format either date has ['-', '/'] SELECT CAST('2012-02-23' AS TIME) GO ~~START~~ @@ -17,7 +19,23 @@ time ~~END~~ -SELECT CAST('12 jan 20 2:3' AS TIME) +SELECT CAST('2012 - 02 - 23' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : ' AS TIME) +GO +~~START~~ +time +02:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3' AS TIME) GO ~~START~~ time @@ -25,7 +43,64 @@ time ~~END~~ -SELECT CAST('2012 - fEb - 23' AS TIME) +SELECT CAST('2012 - 02 - 23 2 : 3 :' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 / 02 / 23 2 : 3 : 8' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 / 02 / 23 2 : 3 : 8 . 876' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +-- when month is given text format either date has ['-', '/'] +SELECT CAST('2012-02-23' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 - FeBruAry - 23' AS TIME) GO ~~START~~ time @@ -33,7 +108,72 @@ time ~~END~~ -SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(0)) +SELECT CAST('2012 - feb - 23 2 : ' AS TIME) +GO +~~START~~ +time +02:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 :' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 / FeB / 23 2 : 3 : 8' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 / FeB / 23 2 : 3 : 8 . 876' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 - FeBruary - 23 2 : 3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +-- casting to particular round off, valid in range of [0-7] +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(0)) GO ~~START~~ time @@ -41,20 +181,118 @@ time ~~END~~ -SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(1)) GO ~~START~~ time -01:05:06.2890000 +01:05:06.3 ~~END~~ --- these particular cases are failing in SQL Server but passing in bbf -SELECT CAST('121200' AS TIME) +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(2)) GO ~~START~~ time -12:12:00.0000000 +01:05:06.29 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(3)) +GO +~~START~~ +time +01:05:06.289 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(4)) +GO +~~START~~ +time +01:05:06.2890 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(5)) +GO +~~START~~ +time +01:05:06.28900 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(6)) +GO +~~START~~ +time +01:05:06.289000 +~~END~~ + + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(7)) +GO +~~START~~ +time +01:05:06.289000 +~~END~~ + + +-- These particular cases are failing in bbf but passing in sql Server +SELECT CAST('12 jan 20 2:3' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + + +-- These particular cases are failing in SQL Server but passing in bbf +-- case where if we mention input has milli seconds(".") and no digit after that and valid offset("+-") and for valid range +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME(0)) +GO +~~START~~ +time +02:03:08 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 + 8' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 - 8' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 + 8' AS TIME(0)) +GO +~~START~~ +time +02:03:09 +~~END~~ + + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 - 8' AS TIME(0)) +GO +~~START~~ +time +02:03:09 ~~END~~ @@ -66,11 +304,93 @@ time ~~END~~ -SELECT CAST('Jan 2021 01 010506.289' AS TIME) +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 .' AS TIME) +GO +~~START~~ +time +02:03:08.0000000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 .' AS TIME(0)) +GO +~~START~~ +time +02:03:08 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 + 8' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 - 8' AS TIME) +GO +~~START~~ +time +02:03:08.8760000 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 + 8' AS TIME(0)) +GO +~~START~~ +time +02:03:09 +~~END~~ + + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 - 8' AS TIME(0)) +GO +~~START~~ +time +02:03:09 +~~END~~ + + +-- case for different types of date format(mm-dd-yyyy, mm-yyyy-dd) +SELECT CAST('Jan-01-2001' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) +GO +~~START~~ +time +01:05:06.2890000 +~~END~~ + + +SELECT CAST('Jan-2021-01' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +GO +~~START~~ +time +01:05:06.2890000 +~~END~~ + + +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "Jan 2021 01 010506.289")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT CAST('Jan-2021-01 121200 -1' AS TIME) @@ -81,57 +401,189 @@ time ~~END~~ -select CAST(CAST('2020 - 03 - 15' AS date) AS time); +-- if input is given in hhmmss +SELECT CAST('121200' AS TIME) +GO +~~START~~ +time +12:12:00.0000000 +~~END~~ + + +SELECT CAST('001200' AS TIME) +GO +~~START~~ +time +00:12:00.0000000 +~~END~~ + + +SELECT CAST('0012:00' AS TIME) GO --~~START~~ --datetime --2020-03-15 00:00:00.0 --~~END~~ +~~START~~ +time +12:00:00.0000000 +~~END~~ -- Negative cases +-- wrong dates has been passed as an input +SELECT CAST('Jan-0000-01' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Jan-2021-34' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Month-2021-01' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- casting to time from date shouldn't be allowed +select CAST(CAST('2020-03-15' AS date) AS time); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type date to time without time zone)~~ + + +-- out of range should throw error +SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(8)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Specified scale 8 is invalid. 'time' datatype must have scale between 0 and 7)~~ + + +-- case for different types of date format(dd-yyyy-mm, yyyy-dd-mm, mm-yyyy-dd) +SELECT CAST('3-2021-jan 01:05:06.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('2003-30-jan 01:05:06.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "Jan-2021-01 121200 1-1")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('+02' AS TIME); +-- case where the yyyy is not able to figure out from given input which contains yy +SELECT CAST('3-01-jan 01:05:06.289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "+02")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('20121200' AS TIME) +-- if given hh:mmmm +SELECT CAST('00:1200' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "20121200")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +--if given yyyymmdd as input SELECT CAST('2012jan00' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "2012jan00")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('20121200' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT CAST('Jan 2021 010506.289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "Jan 2021 010506.289")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: invalid input syntax for type time: "Jan 2021 01 01 05 06 . 289")~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- if invalid dates has been given then conversion shouldn't succeed +SELECT CAST('0000-00-00' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('0-0-0' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('00-00-0000' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('00-0-0' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('0-0-00' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +-- need to check SELECT CAST('Jan-2021-01 121200 ' AS TIME) GO ~~ERROR (Code: 33557097)~~ diff --git a/test/JDBC/input/babel_datatype.sql b/test/JDBC/input/babel_datatype.sql index 60d34e2639..a6991d16f6 100644 --- a/test/JDBC/input/babel_datatype.sql +++ b/test/JDBC/input/babel_datatype.sql @@ -233,31 +233,6 @@ select CAST('2020-03-15 09:00:00' AS datetime2); GO select CAST('2020-03-15 09:00:00' AS smalldatetime); GO -select CAST('2020-MarCh-15' AS date); -GO -select CAST('2020-mar-15 09:00:00+8' AS datetimeoffset); -GO -select CAST('2020-MAR-15 09:00:00' AS datetime2); -GO -select CAST('2020-MaR-15 09:00:00' AS smalldatetime); -GO - -select CAST('2020 - 03 - 15' AS date); -GO -select CAST('2020 - 03-15 09 : 00 : 00 + 8' AS datetimeoffset); -GO -select CAST('2020-03 -15 09 : 00 : 00' AS datetime2); -GO -select CAST('2020-03- 15 09 : 00 : 00' AS smalldatetime); -GO -select CAST('2020 -MarCh-15 09 : 00: 00+8' AS date); -GO -select CAST('2020- mar-15 09:00:00+8' AS datetimeoffset); -GO -select CAST('2020- MAR -15 09 : 00 : 00' AS datetime2); -GO -select CAST('2020 - MaR - 15 09:00:00' AS smalldatetime); -GO -- test the range of date select CAST('0001-01-01' AS date); diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index 965cf8c61a..da359da16e 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -1,58 +1,246 @@ -- psql +-- behaviour of casting to time in psql SELECT CAST('2012-02-23' AS TIME) GO -- tsql +-- when month is given in nymeric format either date has ['-', '/'] SELECT CAST('2012-02-23' AS TIME) GO +SELECT CAST('2012 - 02 - 23' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : ' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3 :' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8' AS TIME) +GO + +SELECT CAST('2012 / 02 / 23 2 : 3 : 8' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876' AS TIME) +GO + +SELECT CAST('2012 / 02 / 23 2 : 3 : 8 . 876' AS TIME) +GO + +-- when month is given text format either date has ['-', '/'] +SELECT CAST('2012-02-23' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23' AS TIME) +GO + +SELECT CAST('2012 - FeBruAry - 23' AS TIME) +GO + +SELECT CAST('2012 - feb - 23 2 : ' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 :' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8' AS TIME) +GO + +SELECT CAST('2012 / FeB / 23 2 : 3 : 8' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876' AS TIME) +GO + +SELECT CAST('2012 / FeB / 23 2 : 3 : 8 . 876' AS TIME) +GO + +SELECT CAST('2012 - FeBruary - 23 2 : 3' AS TIME) +GO + +-- casting to particular round off, valid in range of [0-7] +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(0)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(1)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(2)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(3)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(4)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(5)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(6)) +GO + +SELECT CAST('2015-03-19 01:05:06.289' AS TIME(7)) +GO + +-- These particular cases are failing in bbf but passing in sql Server SELECT CAST('12 jan 20 2:3' AS TIME) GO -SELECT CAST('2012 - fEb - 23' AS TIME) + +-- These particular cases are failing in SQL Server but passing in bbf +-- case where if we mention input has milli seconds(".") and no digit after that and valid offset("+-") and for valid range +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME) GO -SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(0)) +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME(0)) GO -SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 + 8' AS TIME) GO --- these particular cases are failing in SQL Server but passing in bbf -SELECT CAST('121200' AS TIME) +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 - 8' AS TIME) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 + 8' AS TIME(0)) +GO + +SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876 - 8' AS TIME(0)) GO SELECT CAST('2012- 02- 23 02 : 03 : 00 + 8' AS TIME) GO -SELECT CAST('Jan 2021 01 010506.289' AS TIME) +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 .' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 .' AS TIME(0)) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 + 8' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 - 8' AS TIME) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 + 8' AS TIME(0)) +GO + +SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 - 8' AS TIME(0)) +GO + +-- case for different types of date format(mm-dd-yyyy, mm-yyyy-dd) +SELECT CAST('Jan-01-2001' AS TIME) +GO + +SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) +GO + +SELECT CAST('Jan-2021-01' AS TIME) +GO + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +GO + +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); GO SELECT CAST('Jan-2021-01 121200 -1' AS TIME) GO -select CAST(CAST('2020 - 03 - 15' AS date) AS time); +-- if input is given in hhmmss +SELECT CAST('121200' AS TIME) +GO + +SELECT CAST('001200' AS TIME) +GO + +SELECT CAST('0012:00' AS TIME) GO -- Negative cases +-- wrong dates has been passed as an input +SELECT CAST('Jan-0000-01' AS TIME) +GO + +SELECT CAST('Jan-2021-34' AS TIME) +GO + +SELECT CAST('Month-2021-01' AS TIME) +GO + +-- casting to time from date shouldn't be allowed +select CAST(CAST('2020-03-15' AS date) AS time); +GO + +-- out of range should throw error +SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(8)) +GO + +-- case for different types of date format(dd-yyyy-mm, yyyy-dd-mm, mm-yyyy-dd) +SELECT CAST('3-2021-jan 01:05:06.289' AS TIME) +GO + +SELECT CAST('2003-30-jan 01:05:06.289' AS TIME) +GO + SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) GO -SELECT CAST('+02' AS TIME); +-- case where the yyyy is not able to figure out from given input which contains yy +SELECT CAST('3-01-jan 01:05:06.289' AS TIME) GO -SELECT CAST('20121200' AS TIME) +-- if given hh:mmmm +SELECT CAST('00:1200' AS TIME) GO +--if given yyyymmdd as input SELECT CAST('2012jan00' AS TIME) GO +SELECT CAST('20121200' AS TIME) +GO + +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO + SELECT CAST('Jan 2021 010506.289' AS TIME) GO SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) GO +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); +GO + +-- if invalid dates has been given then conversion shouldn't succeed +SELECT CAST('0000-00-00' AS TIME) +GO + +SELECT CAST('0-0-0' AS TIME) +GO + +SELECT CAST('00-00-0000' AS TIME) +GO + +SELECT CAST('00-0-0' AS TIME) +GO + +SELECT CAST('0-0-00' AS TIME) +GO + +-- need to check SELECT CAST('Jan-2021-01 121200 ' AS TIME) GO From 5970208ed184a9284c000ab81888d85710b3a948 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Mon, 14 Aug 2023 06:40:49 +0000 Subject: [PATCH 03/27] Add support for 'dd mon yyyy' syntax and add tests --- contrib/babelfishpg_tsql/src/hooks.c | 52 ++++++++++++++++++ contrib/babelfishpg_tsql/src/tsqlIface.cpp | 10 ++-- test/JDBC/expected/babel_time-vu-verify.out | 58 +++++++++++++-------- test/JDBC/input/babel_time-vu-verify.mix | 17 ++++-- 4 files changed, 106 insertions(+), 31 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 990ef35034..b1f1e39e7d 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -140,6 +140,8 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); static void pltsql_parse_time_error(int dterr, const char *str, const char *datatype); +static void pltsql_modify_fields(int *nf, char **field, int *ftype); +bool containsInMonthFormat(int *ftype); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, QueryEnvironment *queryEnv, ParamListInfo params, QueryCompletion *qc); @@ -216,6 +218,7 @@ static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_v static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; static time_hook_type prev_time_hook = NULL; +static modify_field_hook_type prev_modify_field_hook = NULL; /***************************************** * Install / Uninstall @@ -369,6 +372,9 @@ InstallExtendedHooks(void) prev_time_hook = time_hook; time_hook = pltsql_parse_time_error; + + prev_modify_field_hook = modify_field_hook; + modify_field_hook = pltsql_modify_fields; } void @@ -428,6 +434,7 @@ UninstallExtendedHooks(void) IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; time_hook = prev_time_hook; + modify_field_hook = prev_modify_field_hook; } /***************************************** @@ -2662,6 +2669,51 @@ void pltsql_parse_time_error(int dterr, const char *str, const char *datatype) } } +/* + * Modify the given input of type 'dd mon yyyy' to 'dd-mon-yyyy' + */ +void pltsql_modify_fields(int *nf, char **field, int *ftype) +{ + // field[0] = field[0] + field[1] + field[2] + if(containsInMonthFormat(ftype)) + { + StringInfoData buf; + initStringInfo(&buf); + appendStringInfoString(&buf, field[0]); + for(int i=1;i<3;i++) + { + appendStringInfoString(&buf, "-"); + appendStringInfoString(&buf, field[i]); + + } + field[0]=buf.data; + ftype[0] = 2; + *nf = *nf - 2; + for(int i = 1; i < *nf; i++) + { + field[i] = field[i+2]; + ftype[i] = ftype[i+2]; + } + + } +} + +bool containsInMonthFormat(int *ftype){ + int count0 = 0, count1 = 0; + for(int i=0;i<3;i++) + { + if(ftype[i] == 0) + count0++; + else if(ftype[i] == 1) + count1++; + else + return false; + } + if(count0 ==2 && count1 ==1) + return true; + return false; +} + /* * Stores argument positions of default values of a PL/tsql function to bbf_function_ext catalog */ diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 39cf82ea54..42c65026ca 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1923,13 +1923,15 @@ class tsqlBuilder : public tsqlCommonMutator if(bctx->bif_cast_parse() && bctx->bif_cast_parse()->bif && bctx->bif_cast_parse()->bif) { auto temp = bctx->bif_cast_parse(); - if(temp->data_type() && (pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0 || - pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "DATE", 4) == 0 || - pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "SMALLDATETIME", 13) == 0)) + if(temp->data_type() && (pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0) { std::string s(pstrdup(::getFullText(temp->expression()).c_str())); - std::regex pattern("\\s*([-/:.])\\s*"); + /* Remove spaces between time and date in format of dd/mm/yyyy */ + std::regex pattern("\\s*([/:.])\\s*"); std::string result = std::regex_replace(s, pattern, "$1"); + /* Remove spaces in between date in format of dd / mm / yyyy */ + pattern = ("\\s*(\\d{2,4}|\\w+)\\s*([-/])\\s*(\\d{1,2}|\\w+)\\s*([-/])\\s*(\\d{1,4}|\\w+)\\s*"); + result = std::regex_replace(result, pattern, "$1$2$3$4$5 "); if ( s!= result) rewritten_query_fragment.emplace(std::make_pair(temp->expression()->start->getStartIndex(), std::make_pair(::getFullText(temp->expression()), result))); } diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out index bdef0888ee..e916c5e0c1 100644 --- a/test/JDBC/expected/babel_time-vu-verify.out +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -4,7 +4,7 @@ SELECT CAST('2012-02-23' AS TIME) GO ~~ERROR (Code: 0)~~ -~~ERROR (Message: ERROR: invalid input syntax for type time: "2012-02-23" +~~ERROR (Message: ERROR: Conversion failed when converting date and/or time from character string. Position: 53 Server SQLState: 22007)~~ @@ -237,13 +237,28 @@ time ~~END~~ --- These particular cases are failing in bbf but passing in sql Server SELECT CAST('12 jan 20 2:3' AS TIME) GO -~~ERROR (Code: 33557097)~~ +~~START~~ +time +02:03:00.0000000 +~~END~~ -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +SELECT CAST('jan 12 20 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('jan 2012 12 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ -- These particular cases are failing in SQL Server but passing in bbf @@ -385,22 +400,6 @@ time ~~END~~ --- if only offset is mentioned -SELECT CAST('+02' AS TIME); -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ - - -SELECT CAST('Jan-2021-01 121200 -1' AS TIME) -GO -~~START~~ -time -12:12:00.0000000 -~~END~~ - - -- if input is given in hhmmss SELECT CAST('121200' AS TIME) GO @@ -427,6 +426,14 @@ time -- Negative cases +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + -- wrong dates has been passed as an input SELECT CAST('Jan-0000-01' AS TIME) GO @@ -522,7 +529,7 @@ SELECT CAST('Jan 2021 01 010506.289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ SELECT CAST('Jan 2021 010506.289' AS TIME) @@ -536,7 +543,7 @@ SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ -- if only offset is mentioned @@ -591,6 +598,13 @@ GO ~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ +SELECT CAST('Jan-2021-01 121200 -1' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ + + SELECT * from babel_TIME_vu_prepare_t1 GO ~~START~~ diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index da359da16e..fd5d50067d 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -91,10 +91,14 @@ GO SELECT CAST('2015-03-19 01:05:06.289' AS TIME(7)) GO --- These particular cases are failing in bbf but passing in sql Server SELECT CAST('12 jan 20 2:3' AS TIME) GO +SELECT CAST('jan 12 20 2:3' AS TIME) +GO + +SELECT CAST('jan 2012 12 2:3' AS TIME) +GO -- These particular cases are failing in SQL Server but passing in bbf -- case where if we mention input has milli seconds(".") and no digit after that and valid offset("+-") and for valid range @@ -150,10 +154,6 @@ GO SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) GO --- if only offset is mentioned -SELECT CAST('+02' AS TIME); -GO - SELECT CAST('Jan-2021-01 121200 -1' AS TIME) GO @@ -168,6 +168,10 @@ SELECT CAST('0012:00' AS TIME) GO -- Negative cases +-- if only offset is mentioned +SELECT CAST('+02' AS TIME); +GO + -- wrong dates has been passed as an input SELECT CAST('Jan-0000-01' AS TIME) GO @@ -244,6 +248,9 @@ GO SELECT CAST('Jan-2021-01 121200 ' AS TIME) GO +SELECT CAST('Jan-2021-01 121200 -1' AS TIME) +GO + SELECT * from babel_TIME_vu_prepare_t1 GO From 5abb533425f020d976bd87c8ff000d8ea16bc3fc Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Mon, 14 Aug 2023 08:49:43 +0000 Subject: [PATCH 04/27] Fix build failure --- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 2 +- test/JDBC/expected/babel_datatype.out | 6 ------ test/JDBC/input/babel_datatype.sql | 6 ------ test/JDBC/input/babel_time-vu-verify.mix | 3 --- 4 files changed, 1 insertion(+), 16 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 42c65026ca..728da688c8 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1923,7 +1923,7 @@ class tsqlBuilder : public tsqlCommonMutator if(bctx->bif_cast_parse() && bctx->bif_cast_parse()->bif && bctx->bif_cast_parse()->bif) { auto temp = bctx->bif_cast_parse(); - if(temp->data_type() && (pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0) + if(temp->data_type() && pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0) { std::string s(pstrdup(::getFullText(temp->expression()).c_str())); /* Remove spaces between time and date in format of dd/mm/yyyy */ diff --git a/test/JDBC/expected/babel_datatype.out b/test/JDBC/expected/babel_datatype.out index b458f472d4..2d9bf5db06 100644 --- a/test/JDBC/expected/babel_datatype.out +++ b/test/JDBC/expected/babel_datatype.out @@ -648,7 +648,6 @@ smalldatetime 2020-03-15 09:00:00.0 ~~END~~ - -- test the range of date select CAST('0001-01-01' AS date); GO @@ -1551,11 +1550,6 @@ postgres ~~END~~ -DROP TABLE s1.test1; -go - -DROP SCHEMA s1; -GO -- test tinyint data type select CAST(100 AS tinyint); diff --git a/test/JDBC/input/babel_datatype.sql b/test/JDBC/input/babel_datatype.sql index a6991d16f6..e85d5763ce 100644 --- a/test/JDBC/input/babel_datatype.sql +++ b/test/JDBC/input/babel_datatype.sql @@ -233,7 +233,6 @@ select CAST('2020-03-15 09:00:00' AS datetime2); GO select CAST('2020-03-15 09:00:00' AS smalldatetime); GO - -- test the range of date select CAST('0001-01-01' AS date); GO @@ -625,11 +624,6 @@ GO SELECT set_config('babelfishpg_tsql.sql_dialect', 'postgres', false); GO -DROP TABLE s1.test1; -go - -DROP SCHEMA s1; -GO -- test tinyint data type select CAST(100 AS tinyint); diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index fd5d50067d..02eb3a53a3 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -154,9 +154,6 @@ GO SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) GO -SELECT CAST('Jan-2021-01 121200 -1' AS TIME) -GO - -- if input is given in hhmmss SELECT CAST('121200' AS TIME) GO From ef3b0a56d4b792dd211d18aaa8d54c463d94f8d6 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Mon, 14 Aug 2023 10:30:20 +0000 Subject: [PATCH 05/27] Empty commit From 45d14eebadb0713e982e683d1d5bb38f14892a6d Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Tue, 22 Aug 2023 09:58:37 +0000 Subject: [PATCH 06/27] Rename hooks, add hook for handling month case and add tests --- contrib/babelfishpg_tsql/src/hooks.c | 122 +++++++++-------- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 36 +++-- test/JDBC/expected/babel_time-vu-verify.out | 139 +++++++++++++------- test/JDBC/input/babel_time-vu-verify.mix | 68 ++++++---- 4 files changed, 228 insertions(+), 137 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index b1f1e39e7d..e538eb1d82 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -45,6 +45,7 @@ #include "tcop/utility.h" #include "utils/builtins.h" #include "utils/date.h" +#include "utils/datetime.h" #include "utils/fmgroids.h" #include "utils/lsyscache.h" #include "utils/rel.h" @@ -140,8 +141,8 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); static void pltsql_parse_time_error(int dterr, const char *str, const char *datatype); -static void pltsql_modify_fields(int *nf, char **field, int *ftype); -bool containsInMonthFormat(int *ftype); +static bool pltsql_handle_textMonth_case(int type, bool *haveTextMonth, int fmask, int *tmask, struct pg_tm *tm, int val); +static int pltsql_date_decoder(int nf, char **field, int fmask, int tmask, bool is2digits, struct pg_tm *tm, bool bc, bool isjulian); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, QueryEnvironment *queryEnv, ParamListInfo params, QueryCompletion *qc); @@ -217,8 +218,9 @@ static table_variable_satisfies_update_hook_type prev_table_variable_satisfies_u static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_vacuum = NULL; static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; -static time_hook_type prev_time_hook = NULL; -static modify_field_hook_type prev_modify_field_hook = NULL; +static time_datatype_parse_error_hook_type prev_time_datatype_parse_error_hook = NULL; +static date_decoder_hook_type prev_date_decoder_hook = NULL; +static handle_textMonth_case_hook_type prev_handle_textMonth_case_hook = NULL; /***************************************** * Install / Uninstall @@ -370,11 +372,14 @@ InstallExtendedHooks(void) prev_drop_relation_refcnt_hook = drop_relation_refcnt_hook; drop_relation_refcnt_hook = pltsql_drop_relation_refcnt_hook; - prev_time_hook = time_hook; - time_hook = pltsql_parse_time_error; + prev_time_datatype_parse_error_hook = time_datatype_parse_error_hook; + time_datatype_parse_error_hook = pltsql_parse_time_error; - prev_modify_field_hook = modify_field_hook; - modify_field_hook = pltsql_modify_fields; + prev_date_decoder_hook = date_decoder_hook; + date_decoder_hook = pltsql_date_decoder; + + prev_handle_textMonth_case_hook = handle_textMonth_case_hook; + handle_textMonth_case_hook = pltsql_handle_textMonth_case; } void @@ -433,8 +438,9 @@ UninstallExtendedHooks(void) IsToastRelationHook = PrevIsToastRelationHook; IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; - time_hook = prev_time_hook; - modify_field_hook = prev_modify_field_hook; + time_datatype_parse_error_hook = prev_time_datatype_parse_error_hook; + date_decoder_hook = prev_date_decoder_hook; + handle_textMonth_case_hook = prev_handle_textMonth_case_hook; } /***************************************** @@ -2655,63 +2661,73 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume } /* - * Throw a common error message while casting to time datatype + * Handle the case where month is given in text format */ -void pltsql_parse_time_error(int dterr, const char *str, const char *datatype) +bool pltsql_handle_textMonth_case(int type, bool *haveTextMonth, int fmask, int *tmask, struct pg_tm *tm, int val) { - switch (dterr) + if(sql_dialect == SQL_DIALECT_TSQL && type == MONTH) { - default: - ereport(ERROR, - (errcode(ERRCODE_INVALID_DATETIME_FORMAT), - errmsg("Conversion failed when converting date and/or time from character string."))); - break; + /* + * already have a (numeric) month? then see if we can + * substitute... + */ + if ((fmask & DTK_M(MONTH)) && !*haveTextMonth && + !(fmask & DTK_M(DAY)) && tm->tm_mon >= 1 && + tm->tm_mon <= 31) + { + tm->tm_mday = tm->tm_mon; + *tmask = DTK_M(DAY); + } + *haveTextMonth = true; + tm->tm_mon = val; + return true; } + return false; } - /* - * Modify the given input of type 'dd mon yyyy' to 'dd-mon-yyyy' + * Throw a common error message while casting to time datatype */ -void pltsql_modify_fields(int *nf, char **field, int *ftype) +void pltsql_parse_time_error(int dterr, const char *str, const char *datatype) { - // field[0] = field[0] + field[1] + field[2] - if(containsInMonthFormat(ftype)) - { - StringInfoData buf; - initStringInfo(&buf); - appendStringInfoString(&buf, field[0]); - for(int i=1;i<3;i++) - { - appendStringInfoString(&buf, "-"); - appendStringInfoString(&buf, field[i]); - - } - field[0]=buf.data; - ftype[0] = 2; - *nf = *nf - 2; - for(int i = 1; i < *nf; i++) + if(sql_dialect == SQL_DIALECT_TSQL) + switch (dterr) { - field[i] = field[i+2]; - ftype[i] = ftype[i+2]; + default: + ereport(ERROR, + (errcode(ERRCODE_INVALID_DATETIME_FORMAT), + errmsg("Conversion failed when converting date and/or time from character string."))); + break; } - - } } -bool containsInMonthFormat(int *ftype){ - int count0 = 0, count1 = 0; - for(int i=0;i<3;i++) +/* + * If the input contains only date field then validate the input. + * If contains more fields(date, time, offset) then do nothing and continue with the next step. + */ +int pltsql_date_decoder(int nf, char **field, int fmask, int tmask, bool is2digits, struct pg_tm *tm, bool bc, bool isjulian) +{ + if (sql_dialect == SQL_DIALECT_TSQL && nf == 1) { - if(ftype[i] == 0) - count0++; - else if(ftype[i] == 1) - count1++; - else - return false; + /* do final checking/adjustment of Y/M/D fields */ + int dterr = DecodeDateWrapper(field[0], fmask, + &tmask, &is2digits, tm); + if (dterr) + return dterr; + + if (tmask & fmask) + return DTERR_BAD_FORMAT; + fmask |= tmask; + + /* do final checking/adjustment of Y/M/D fields */ + dterr = ValidateDate(fmask, isjulian, is2digits, bc, tm); + if (dterr) + return dterr; + + /* No error then just return 0 */ + return 0; } - if(count0 ==2 && count1 ==1) - return true; - return false; + /* returning -6 as the given input is not of format 'yyyy-mm-dd' */ + return -6; } /* diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 728da688c8..4b7bbdf5d4 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1920,20 +1920,34 @@ class tsqlBuilder : public tsqlCommonMutator if (bctx->bif_no_brackets && bctx->SESSION_USER()) rewritten_query_fragment.emplace(std::make_pair(bctx->bif_no_brackets->getStartIndex(), std::make_pair(::getFullText(bctx->SESSION_USER()), "sys.session_user()"))); - if(bctx->bif_cast_parse() && bctx->bif_cast_parse()->bif && bctx->bif_cast_parse()->bif) + if(bctx->bif_cast_parse()) { - auto temp = bctx->bif_cast_parse(); - if(temp->data_type() && pg_strncasecmp(::getFullText(temp->data_type()).c_str(), "TIME", 4) == 0) + auto cast_parse = bctx->bif_cast_parse(); + /* Re-write the expression for casting to time datatype. */ + if(cast_parse->data_type() && pg_strncasecmp(::getFullText(cast_parse->data_type()).c_str(), "TIME", 4) == 0) { - std::string s(pstrdup(::getFullText(temp->expression()).c_str())); - /* Remove spaces between time and date in format of dd/mm/yyyy */ + std::string cast_expression(pstrdup(::getFullText(cast_parse->expression()).c_str())); + + /* + * Remove spaces between before or after {/:.} in the given expression. + * If the expression contains input of ' dd / mm/ yyyy hh: mm : ss . ss' + * will be converted to ' dd/mm/yyyy hh:mm:ss.ss' + */ std::regex pattern("\\s*([/:.])\\s*"); - std::string result = std::regex_replace(s, pattern, "$1"); - /* Remove spaces in between date in format of dd / mm / yyyy */ - pattern = ("\\s*(\\d{2,4}|\\w+)\\s*([-/])\\s*(\\d{1,2}|\\w+)\\s*([-/])\\s*(\\d{1,4}|\\w+)\\s*"); - result = std::regex_replace(result, pattern, "$1$2$3$4$5 "); - if ( s!= result) - rewritten_query_fragment.emplace(std::make_pair(temp->expression()->start->getStartIndex(), std::make_pair(::getFullText(temp->expression()), result))); + std::string result_expression = std::regex_replace(cast_expression, pattern, "$1"); + + /* + * Remove spaces in between date in different kind of format dd {-} mm {-} yyyy. + * The {-} was not included above as the timezone can contain {+,-} which shouldn't be affected. + * For example if the expression contains ' dd - mm -yyyy hh:mm' + * will be converted to ' dd-mm-yyyy hh:mm' + */ + pattern = ("\\s*(\\d{2,4}|\\w+)\\s*(-)\\s*(\\d{1,2}|\\w+)\\s*(-)\\s*(\\d{1,4}|\\w+)\\s*"); + result_expression = std::regex_replace(result_expression, pattern, "$1$2$3$4$5 "); + + /* If the expression didn't change after comparing with above regex no need to change */ + if ( cast_expression!= result_expression) + rewritten_query_fragment.emplace(std::make_pair(cast_parse->expression()->start->getStartIndex(), std::make_pair(::getFullText(cast_parse->expression()), result_expression))); } } } diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out index e916c5e0c1..542ef8e75a 100644 --- a/test/JDBC/expected/babel_time-vu-verify.out +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -4,13 +4,13 @@ SELECT CAST('2012-02-23' AS TIME) GO ~~ERROR (Code: 0)~~ -~~ERROR (Message: ERROR: Conversion failed when converting date and/or time from character string. +~~ERROR (Message: ERROR: invalid input syntax for type time: "2012-02-23" Position: 53 Server SQLState: 22007)~~ -- tsql --- when month is given in nymeric format either date has ['-', '/'] +-- when month is given in numeric format and date can have ['-', '/'] SELECT CAST('2012-02-23' AS TIME) GO ~~START~~ @@ -19,7 +19,7 @@ time ~~END~~ -SELECT CAST('2012 - 02 - 23' AS TIME) +SELECT CAST(' 2012 - 02 - 23 ' AS TIME) GO ~~START~~ time @@ -83,7 +83,7 @@ time ~~END~~ --- when month is given text format either date has ['-', '/'] +-- when month is given text format and date can have ['-', '/', ' '] SELECT CAST('2012-02-23' AS TIME) GO ~~START~~ @@ -172,6 +172,38 @@ time ~~END~~ +SELECT CAST('12 jan 20 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('12 decemBer 20 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('jan 12 20 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + +SELECT CAST('jan 2012 12 2:3' AS TIME) +GO +~~START~~ +time +02:03:00.0000000 +~~END~~ + + -- casting to particular round off, valid in range of [0-7] SELECT CAST('2015-03-19 01:05:06.289' AS TIME(0)) GO @@ -237,32 +269,65 @@ time ~~END~~ -SELECT CAST('12 jan 20 2:3' AS TIME) +-- multiple casting +SELECT CAST(CAST('2000-11-23' AS DATETIME) AS TIME) GO ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('jan 12 20 2:3' AS TIME) -GO +select CAST(CAST('00:00:00.000' AS time) AS datetime) +go +~~START~~ +datetime +1900-01-01 00:00:00.0 +~~END~~ + + +select CAST(CAST('2000-11-23' AS time) AS datetime) +go +~~START~~ +datetime +1900-01-01 00:00:00.0 +~~END~~ + +select CAST(CAST('23:59:59.123456' AS time) AS datetime) +go +~~START~~ +datetime +1900-01-01 23:59:59.123 +~~END~~ + + +select CAST(CAST('1900-05-06 23:59:29.998' AS datetime) AS time) +go ~~START~~ time -02:03:00.0000000 +23:59:29.9980000 ~~END~~ -SELECT CAST('jan 2012 12 2:3' AS TIME) -GO +select CAST(CAST('2050-05-06 00:00:00' AS datetime) AS time) +go ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 +~~END~~ + + +select CAST(CAST('2050-05-06 23:59:29.998' AS datetime) AS time) +go +~~START~~ +time +23:59:29.9980000 ~~END~~ -- These particular cases are failing in SQL Server but passing in bbf --- case where if we mention input has milli seconds(".") and no digit after that and valid offset("+-") and for valid range +-- case where if we mention input has no milli seconds mentioned after (".") +-- and cases when valid offset("+-") and for valid range SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME) GO ~~START~~ @@ -400,6 +465,15 @@ time ~~END~~ +-- case where input is of format 'mm yyyy dd hhmmss.ss' +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO +~~START~~ +time +01:05:06.2890000 +~~END~~ + + -- if input is given in hhmmss SELECT CAST('121200' AS TIME) GO @@ -434,7 +508,7 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- wrong dates has been passed as an input +-- Invalid dates has been passed as an input SELECT CAST('Jan-0000-01' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -464,7 +538,7 @@ GO ~~ERROR (Message: cannot cast type date to time without time zone)~~ --- out of range should throw error +-- out of range for time datatype should throw error SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(8)) GO ~~ERROR (Code: 33557097)~~ @@ -472,28 +546,6 @@ GO ~~ERROR (Message: Specified scale 8 is invalid. 'time' datatype must have scale between 0 and 7)~~ --- case for different types of date format(dd-yyyy-mm, yyyy-dd-mm, mm-yyyy-dd) -SELECT CAST('3-2021-jan 01:05:06.289' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ - - -SELECT CAST('2003-30-jan 01:05:06.289' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ - - -SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ - - -- case where the yyyy is not able to figure out from given input which contains yy SELECT CAST('3-01-jan 01:05:06.289' AS TIME) GO @@ -511,27 +563,20 @@ GO --if given yyyymmdd as input -SELECT CAST('2012jan00' AS TIME) +SELECT CAST('2012jan01' AS TIME) GO ~~ERROR (Code: 33557097)~~ ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('20121200' AS TIME) +SELECT CAST('20121201' AS TIME) GO ~~ERROR (Code: 33557097)~~ ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('Jan 2021 01 010506.289' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ - - SELECT CAST('Jan 2021 010506.289' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -543,7 +588,7 @@ SELECT CAST('Jan 2021 01 01 05 06 . 289' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -- if only offset is mentioned diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index 02eb3a53a3..a220194578 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -4,11 +4,11 @@ SELECT CAST('2012-02-23' AS TIME) GO -- tsql --- when month is given in nymeric format either date has ['-', '/'] +-- when month is given in numeric format and date can have ['-', '/'] SELECT CAST('2012-02-23' AS TIME) GO -SELECT CAST('2012 - 02 - 23' AS TIME) +SELECT CAST(' 2012 - 02 - 23 ' AS TIME) GO SELECT CAST('2012 - 02 - 23 2 : ' AS TIME) @@ -32,7 +32,7 @@ GO SELECT CAST('2012 / 02 / 23 2 : 3 : 8 . 876' AS TIME) GO --- when month is given text format either date has ['-', '/'] +-- when month is given text format and date can have ['-', '/', ' '] SELECT CAST('2012-02-23' AS TIME) GO @@ -66,6 +66,18 @@ GO SELECT CAST('2012 - FeBruary - 23 2 : 3' AS TIME) GO +SELECT CAST('12 jan 20 2:3' AS TIME) +GO + +SELECT CAST('12 decemBer 20 2:3' AS TIME) +GO + +SELECT CAST('jan 12 20 2:3' AS TIME) +GO + +SELECT CAST('jan 2012 12 2:3' AS TIME) +GO + -- casting to particular round off, valid in range of [0-7] SELECT CAST('2015-03-19 01:05:06.289' AS TIME(0)) GO @@ -91,17 +103,30 @@ GO SELECT CAST('2015-03-19 01:05:06.289' AS TIME(7)) GO -SELECT CAST('12 jan 20 2:3' AS TIME) +-- multiple casting +SELECT CAST(CAST('2000-11-23' AS DATETIME) AS TIME) GO -SELECT CAST('jan 12 20 2:3' AS TIME) -GO +select CAST(CAST('00:00:00.000' AS time) AS datetime) +go -SELECT CAST('jan 2012 12 2:3' AS TIME) -GO +select CAST(CAST('2000-11-23' AS time) AS datetime) +go +select CAST(CAST('23:59:59.123456' AS time) AS datetime) +go + +select CAST(CAST('1900-05-06 23:59:29.998' AS datetime) AS time) +go + +select CAST(CAST('2050-05-06 00:00:00' AS datetime) AS time) +go + +select CAST(CAST('2050-05-06 23:59:29.998' AS datetime) AS time) +go -- These particular cases are failing in SQL Server but passing in bbf --- case where if we mention input has milli seconds(".") and no digit after that and valid offset("+-") and for valid range +-- case where if we mention input has no milli seconds mentioned after (".") +-- and cases when valid offset("+-") and for valid range SELECT CAST('2012 - 02 - 23 2 : 3 : 8 .' AS TIME) GO @@ -154,6 +179,10 @@ GO SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) GO +-- case where input is of format 'mm yyyy dd hhmmss.ss' +SELECT CAST('Jan 2021 01 010506.289' AS TIME) +GO + -- if input is given in hhmmss SELECT CAST('121200' AS TIME) GO @@ -169,7 +198,7 @@ GO SELECT CAST('+02' AS TIME); GO --- wrong dates has been passed as an input +-- Invalid dates has been passed as an input SELECT CAST('Jan-0000-01' AS TIME) GO @@ -183,20 +212,10 @@ GO select CAST(CAST('2020-03-15' AS date) AS time); GO --- out of range should throw error +-- out of range for time datatype should throw error SELECT CAST('2015-03-19 01:05:06. 289' AS TIME(8)) GO --- case for different types of date format(dd-yyyy-mm, yyyy-dd-mm, mm-yyyy-dd) -SELECT CAST('3-2021-jan 01:05:06.289' AS TIME) -GO - -SELECT CAST('2003-30-jan 01:05:06.289' AS TIME) -GO - -SELECT CAST('Jan-2021-01 121200 1-1' AS TIME) -GO - -- case where the yyyy is not able to figure out from given input which contains yy SELECT CAST('3-01-jan 01:05:06.289' AS TIME) GO @@ -206,13 +225,10 @@ SELECT CAST('00:1200' AS TIME) GO --if given yyyymmdd as input -SELECT CAST('2012jan00' AS TIME) +SELECT CAST('2012jan01' AS TIME) GO -SELECT CAST('20121200' AS TIME) -GO - -SELECT CAST('Jan 2021 01 010506.289' AS TIME) +SELECT CAST('20121201' AS TIME) GO SELECT CAST('Jan 2021 010506.289' AS TIME) From 2b52253e6de66edb0dcb816e34ac1ae9c820f306 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Tue, 19 Sep 2023 07:40:45 +0000 Subject: [PATCH 07/27] Removed all the logic and called a separate function to handle time datatype --- contrib/babelfishpg_tsql/src/hooks.c | 227 +++++++++---- test/JDBC/expected/babel_time-vu-verify.out | 344 +++++++++++++++++--- test/JDBC/input/babel_time-vu-verify.mix | 167 ++++++++-- 3 files changed, 586 insertions(+), 152 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 95061fa420..5548f879f7 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -40,6 +40,7 @@ #include "parser/parser.h" #include "parser/scanner.h" #include "parser/scansup.h" +#include "regex/regex.h" #include "replication/logical.h" #include "rewrite/rewriteHandler.h" #include "tcop/utility.h" @@ -140,9 +141,9 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, const char *queryString, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); -static void pltsql_parse_time_error(int dterr, const char *str, const char *datatype); -static bool pltsql_handle_textMonth_case(int type, bool *haveTextMonth, int fmask, int *tmask, struct pg_tm *tm, int val); -static int pltsql_date_decoder(int nf, char **field, int fmask, int tmask, bool is2digits, struct pg_tm *tm, bool bc, bool isjulian); +static void gen_func_time_in_error(); +static bool containsInMonthFormat(int *ftype); +static Datum pltsql_time_in(const char *str, int32 typmod); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, QueryEnvironment *queryEnv, ParamListInfo params, QueryCompletion *qc); @@ -229,10 +230,7 @@ static table_variable_satisfies_update_hook_type prev_table_variable_satisfies_u static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_vacuum = NULL; static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; -static time_datatype_parse_error_hook_type prev_time_datatype_parse_error_hook = NULL; -static date_decoder_hook_type prev_date_decoder_hook = NULL; -static handle_textMonth_case_hook_type prev_handle_textMonth_case_hook = NULL; - +static time_in_hook_type prev_time_in_hook = NULL; /***************************************** * Install / Uninstall @@ -394,14 +392,8 @@ InstallExtendedHooks(void) prev_drop_relation_refcnt_hook = drop_relation_refcnt_hook; drop_relation_refcnt_hook = pltsql_drop_relation_refcnt_hook; - prev_time_datatype_parse_error_hook = time_datatype_parse_error_hook; - time_datatype_parse_error_hook = pltsql_parse_time_error; - - prev_date_decoder_hook = date_decoder_hook; - date_decoder_hook = pltsql_date_decoder; - - prev_handle_textMonth_case_hook = handle_textMonth_case_hook; - handle_textMonth_case_hook = pltsql_handle_textMonth_case; + prev_time_in_hook = time_in_hook; + time_in_hook = pltsql_time_in; select_common_type_hook = select_common_type_for_isnull; } @@ -466,9 +458,7 @@ UninstallExtendedHooks(void) IsToastRelationHook = PrevIsToastRelationHook; IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; - time_datatype_parse_error_hook = prev_time_datatype_parse_error_hook; - date_decoder_hook = prev_date_decoder_hook; - handle_textMonth_case_hook = prev_handle_textMonth_case_hook; + time_in_hook = prev_time_in_hook; } /***************************************** @@ -2710,73 +2700,166 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume } /* - * Handle the case where month is given in text format + * Throw a common error message while casting to time datatype */ -bool pltsql_handle_textMonth_case(int type, bool *haveTextMonth, int fmask, int *tmask, struct pg_tm *tm, int val) +static void gen_func_time_in_error() { - if(sql_dialect == SQL_DIALECT_TSQL && type == MONTH) + ereport(ERROR, + (errcode(ERRCODE_INVALID_DATETIME_FORMAT), + errmsg("Conversion failed when converting date and/or time from character string."))); +} + +static bool containsInMonthFormat(int *ftype){ + int count0 = 0, count1 = 0; + for(int i=0;i<3;i++) { - /* - * already have a (numeric) month? then see if we can - * substitute... - */ - if ((fmask & DTK_M(MONTH)) && !*haveTextMonth && - !(fmask & DTK_M(DAY)) && tm->tm_mon >= 1 && - tm->tm_mon <= 31) - { - tm->tm_mday = tm->tm_mon; - *tmask = DTK_M(DAY); - } - *haveTextMonth = true; - tm->tm_mon = val; - return true; + if(ftype[i] == DTK_NUMBER) + count0++; + else if(ftype[i] == DTK_STRING) + /* To-Do Check if valid text month is given */ + count1++; + else + return false; } + if(count0 ==2 && count1 ==1) + return true; return false; } -/* - * Throw a common error message while casting to time datatype - */ -void pltsql_parse_time_error(int dterr, const char *str, const char *datatype) + +Datum pltsql_time_in(const char *str, int32 typmod) { - if(sql_dialect == SQL_DIALECT_TSQL) - switch (dterr) + TimeADT result; + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + int tz; + int nf; + int dterr; + char workbuf[MAXDATELEN + 1]; + char *field[MAXDATEFIELDS]; + int dtype; + int ftype[MAXDATEFIELDS]; + StringInfo sf_1 ; + int status; + + dterr = ParseDateTime(str, workbuf, sizeof(workbuf), + field, ftype, MAXDATEFIELDS, &nf); + if (dterr == 0) + { + if(nf >= 3) + { + if(containsInMonthFormat(ftype)) + { + StringInfoData buf; + initStringInfo(&buf); + appendStringInfoString(&buf, field[0]); + for(int i=1;i<3;i++) + { + appendStringInfoString(&buf, "-"); + appendStringInfoString(&buf, field[i]); + + } + field[0]=buf.data; + ftype[0] = DTK_DATE; + nf = nf - 2; + for(int i = 1; i < nf; i++) + { + field[i] = field[i+2]; + ftype[i] = ftype[i+2]; + } + } + } + + for(int i=0;i < nf; i++) { + switch(ftype[i]) + { + case DTK_NUMBER: + switch(strlen(field[i])) + { + case 1: + case 2: + /* + * At this point the 1,2 digit number should be considered as + * time only if there is an [AP]M after the number or else + * should throw an error + */ + if(i == nf-1 || ftype[i+1] != DTK_STRING) + { + gen_func_time_in_error(); + } + status = RE_compile_and_execute(cstring_to_text("^([AP]M)$"), + (char *) field[i+1], strlen(field[i+1]), + REG_ADVANCED | REG_ICASE, DEFAULT_COLLATION_OID, + 0, NULL); + if(!status) + gen_func_time_in_error(); + + sf_1 = makeStringInfo(); + appendStringInfo(sf_1, "%s%s", field[i], ":0:0"); + field[i] = sf_1->data; + ftype[i] = DTK_TIME; + break; + /* + * To-Do + * Case 6,8 needs special handling to convert the + * given numeric to date format(YYYY-MM-DD/YY-MM-DD) + */ + case 4: + case 6: + case 8: + break; + /* + * If the numeric is of length {3,5,7, >8} then an error should be thrown*/ + default: + gen_func_time_in_error(); + break; + } + } + } + switch(nf) + { + case 1: + /* + * To-Do + * If the input is of format `Mon{/.}yyyy{/.}dd` or `Mon{/.}dd{/.}yyyy + * shouldn't be supported. + */ + /* + * If only date is specified add an default time of + * 0:0:0 + */ + if(ftype[0] == DTK_DATE) + { + ftype[1] = DTK_TIME; + field[1] = "0:0:0"; + nf = nf+1; + } + break; + case 3: + /* + * If the given input is of format `yyyy-mm-ddThh:mm:ss` + * then conver it to `yyyy-mm-dd hh:mm:ss` by ignoring 'T' + */ + if(ftype[1] == DTK_STRING && pg_strcasecmp(field[1], "t") == 0 && ftype[2] == DTK_TIME) + { + ftype[1] = ftype[2]; + field[1] = field[2]; + nf = nf - 1; + } default: - ereport(ERROR, - (errcode(ERRCODE_INVALID_DATETIME_FORMAT), - errmsg("Conversion failed when converting date and/or time from character string."))); break; } -} -/* - * If the input contains only date field then validate the input. - * If contains more fields(date, time, offset) then do nothing and continue with the next step. - */ -int pltsql_date_decoder(int nf, char **field, int fmask, int tmask, bool is2digits, struct pg_tm *tm, bool bc, bool isjulian) -{ - if (sql_dialect == SQL_DIALECT_TSQL && nf == 1) - { - /* do final checking/adjustment of Y/M/D fields */ - int dterr = DecodeDateWrapper(field[0], fmask, - &tmask, &is2digits, tm); - if (dterr) - return dterr; - - if (tmask & fmask) - return DTERR_BAD_FORMAT; - fmask |= tmask; - - /* do final checking/adjustment of Y/M/D fields */ - dterr = ValidateDate(fmask, isjulian, is2digits, bc, tm); - if (dterr) - return dterr; - - /* No error then just return 0 */ - return 0; + dterr = DecodeTimeOnly(field, ftype, nf, &dtype, tm, &fsec, &tz); } - /* returning -6 as the given input is not of format 'yyyy-mm-dd' */ - return -6; + if (dterr != 0) + gen_func_time_in_error(); + + tm2time(tm, fsec, &result); + AdjustTimeForTypmod(&result, typmod); + + PG_RETURN_TIMEADT(result); } /* diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out index 542ef8e75a..f3c17f7dce 100644 --- a/test/JDBC/expected/babel_time-vu-verify.out +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -10,8 +10,31 @@ GO -- tsql --- when month is given in numeric format and date can have ['-', '/'] -SELECT CAST('2012-02-23' AS TIME) +-- if only date is given as input +-- accepted formats are `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` +-- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` +SELECT CAST(' 23 - 11 - 2000 ' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('23-2000-11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11-2000-23' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11-23-2000' AS TIME) GO ~~START~~ time @@ -19,7 +42,7 @@ time ~~END~~ -SELECT CAST(' 2012 - 02 - 23 ' AS TIME) +SELECT CAST('2000-11-23' AS TIME) GO ~~START~~ time @@ -27,64 +50,122 @@ time ~~END~~ -SELECT CAST('2012 - 02 - 23 2 : ' AS TIME) +SELECT CAST('2000-23-11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST(' 23 / 11 / 2000 ' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('23/2000/11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11/2000/23' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11/23/2000' AS TIME) GO ~~START~~ time -02:00:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - 02 - 23 2 : 3' AS TIME) +SELECT CAST('2000/11/23' AS TIME) GO ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - 02 - 23 2 : 3 :' AS TIME) +SELECT CAST('2000/23/11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST(' 23 - Nov - 2000 ' AS TIME) GO ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - 02 - 23 2 : 3 : 8' AS TIME) +SELECT CAST('23-2000-Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov-2000-23' AS TIME) GO ~~START~~ time -02:03:08.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 / 02 / 23 2 : 3 : 8' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov-23-2000' AS TIME) GO ~~START~~ time -02:03:08.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('2000-Nov-23' AS TIME) GO ~~START~~ time -02:03:08.8760000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 / 02 / 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('2000-23-Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST(' 23 / Nov / 2000 ' AS TIME) GO ~~START~~ time -02:03:08.8760000 +00:00:00.0000000 ~~END~~ --- when month is given text format and date can have ['-', '/', ' '] -SELECT CAST('2012-02-23' AS TIME) +SELECT CAST('23/2000/Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov/2000/23' AS TIME) GO ~~START~~ time @@ -92,7 +173,8 @@ time ~~END~~ -SELECT CAST('2012 - FeB - 23' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov/23/2000' AS TIME) GO ~~START~~ time @@ -100,7 +182,7 @@ time ~~END~~ -SELECT CAST('2012 - FeBruAry - 23' AS TIME) +SELECT CAST('2000/Nov/23' AS TIME) GO ~~START~~ time @@ -108,70 +190,237 @@ time ~~END~~ -SELECT CAST('2012 - feb - 23 2 : ' AS TIME) +SELECT CAST('2000/23/Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('23 . 11 . 2000' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('23.2000.11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11.2000.23' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11.23.2000' AS TIME) GO ~~START~~ time -02:00:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - FeB - 23 2 : 3' AS TIME) +SELECT CAST('2000.11.23' AS TIME) GO ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - FeB - 23 2 : 3 :' AS TIME) +SELECT CAST('2000.23.11' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST(' 23 . Nov . 2000 ' AS TIME) GO ~~START~~ time -02:03:00.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - FeB - 23 2 : 3 : 8' AS TIME) +SELECT CAST('23.2000.Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov.2000.23' AS TIME) GO ~~START~~ time -02:03:08.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 / FeB / 23 2 : 3 : 8' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov.23.2000' AS TIME) GO ~~START~~ time -02:03:08.0000000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('2000.Nov.23' AS TIME) GO ~~START~~ time -02:03:08.8760000 +00:00:00.0000000 ~~END~~ -SELECT CAST('2012 / FeB / 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('2000.23.Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +-- If numeric is specified +-- If `am` or `pm` is specified +SELECT CAST('1' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('10' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('102' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + + +-- need handling +-- SELECT CAST('1020' AS TIME) +-- GO +SELECT CAST('10202' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + + +-- need handling +-- SELECT CAST('102022' AS TIME) +-- GO +SELECT CAST('1010101' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + + +-- need handling +-- SELECT CAST('10101010' AS TIME) +-- GO +SELECT CAST('101010101' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('01 Am' AS TIME) GO ~~START~~ time -02:03:08.8760000 +01:00:00.0000000 ~~END~~ -SELECT CAST('2012 - FeBruary - 23 2 : 3' AS TIME) +SELECT CAST('Am 01' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('13 Am' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('01 Pm' AS TIME) GO ~~START~~ time -02:03:00.0000000 +13:00:00.0000000 +~~END~~ + + +SELECT CAST('24 Pm' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('11:58:59 Pm' AS TIME) +GO +~~START~~ +time +23:58:59.0000000 +~~END~~ + + +SELECT CAST('2000-11-23 Am' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('2000-11-23 11:58:59 Pm' AS TIME) +GO +~~START~~ +time +23:58:59.0000000 +~~END~~ + + +-- different kind of input +SELECT CAST('1998-02-23T14:23:05' AS time) +GO +~~START~~ +time +14:23:05.0000000 ~~END~~ +SELECT CAST('1998-02-23num14:23:05' AS time) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + SELECT CAST('12 jan 20 2:3' AS TIME) GO ~~START~~ @@ -468,10 +717,9 @@ time -- case where input is of format 'mm yyyy dd hhmmss.ss' SELECT CAST('Jan 2021 01 010506.289' AS TIME) GO -~~START~~ -time -01:05:06.2890000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -- if input is given in hhmmss @@ -565,16 +813,10 @@ GO --if given yyyymmdd as input SELECT CAST('2012jan01' AS TIME) GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ - - -SELECT CAST('20121201' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +~~START~~ +time +00:00:00.0000000 +~~END~~ SELECT CAST('Jan 2021 010506.289' AS TIME) diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index a220194578..acda83f09d 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -1,69 +1,181 @@ --- psql --- behaviour of casting to time in psql -SELECT CAST('2012-02-23' AS TIME) +-- if only date is given as input +-- accepted formats are `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` +-- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` +SELECT CAST(' 23 - 11 - 2000 ' AS TIME) GO --- tsql --- when month is given in numeric format and date can have ['-', '/'] -SELECT CAST('2012-02-23' AS TIME) +SELECT CAST('23-2000-11' AS TIME) GO -SELECT CAST(' 2012 - 02 - 23 ' AS TIME) +SELECT CAST('11-2000-23' AS TIME) GO -SELECT CAST('2012 - 02 - 23 2 : ' AS TIME) +SELECT CAST('11-23-2000' AS TIME) GO -SELECT CAST('2012 - 02 - 23 2 : 3' AS TIME) +SELECT CAST('2000-11-23' AS TIME) GO -SELECT CAST('2012 - 02 - 23 2 : 3 :' AS TIME) +SELECT CAST('2000-23-11' AS TIME) GO -SELECT CAST('2012 - 02 - 23 2 : 3 : 8' AS TIME) +SELECT CAST(' 23 / 11 / 2000 ' AS TIME) GO -SELECT CAST('2012 / 02 / 23 2 : 3 : 8' AS TIME) +SELECT CAST('23/2000/11' AS TIME) GO -SELECT CAST('2012 - 02 - 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('11/2000/23' AS TIME) GO -SELECT CAST('2012 / 02 / 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('11/23/2000' AS TIME) GO --- when month is given text format and date can have ['-', '/', ' '] -SELECT CAST('2012-02-23' AS TIME) +SELECT CAST('2000/11/23' AS TIME) GO -SELECT CAST('2012 - FeB - 23' AS TIME) +SELECT CAST('2000/23/11' AS TIME) GO -SELECT CAST('2012 - FeBruAry - 23' AS TIME) +SELECT CAST(' 23 - Nov - 2000 ' AS TIME) GO -SELECT CAST('2012 - feb - 23 2 : ' AS TIME) +SELECT CAST('23-2000-Nov' AS TIME) GO -SELECT CAST('2012 - FeB - 23 2 : 3' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov-2000-23' AS TIME) GO -SELECT CAST('2012 - FeB - 23 2 : 3 :' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov-23-2000' AS TIME) GO -SELECT CAST('2012 - FeB - 23 2 : 3 : 8' AS TIME) +SELECT CAST('2000-Nov-23' AS TIME) GO -SELECT CAST('2012 / FeB / 23 2 : 3 : 8' AS TIME) +SELECT CAST('2000-23-Nov' AS TIME) GO -SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST(' 23 / Nov / 2000 ' AS TIME) GO -SELECT CAST('2012 / FeB / 23 2 : 3 : 8 . 876' AS TIME) +SELECT CAST('23/2000/Nov' AS TIME) GO -SELECT CAST('2012 - FeBruary - 23 2 : 3' AS TIME) +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov/2000/23' AS TIME) +GO + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov/23/2000' AS TIME) +GO + +SELECT CAST('2000/Nov/23' AS TIME) +GO + +SELECT CAST('2000/23/Nov' AS TIME) +GO + +SELECT CAST('23 . 11 . 2000' AS TIME) +GO + +SELECT CAST('23.2000.11' AS TIME) +GO + +SELECT CAST('11.2000.23' AS TIME) +GO + +SELECT CAST('11.23.2000' AS TIME) +GO + +SELECT CAST('2000.11.23' AS TIME) +GO + +SELECT CAST('2000.23.11' AS TIME) +GO + +SELECT CAST(' 23 . Nov . 2000 ' AS TIME) +GO + +SELECT CAST('23.2000.Nov' AS TIME) +GO + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov.2000.23' AS TIME) +GO + +-- Need handling(was failing in SQL Server) +SELECT CAST('Nov.23.2000' AS TIME) +GO + +SELECT CAST('2000.Nov.23' AS TIME) +GO + +SELECT CAST('2000.23.Nov' AS TIME) +GO + +-- If numeric is specified +-- If `am` or `pm` is specified +SELECT CAST('1' AS TIME) +GO + +SELECT CAST('10' AS TIME) +GO + +SELECT CAST('102' AS TIME) +GO + +-- need handling +-- SELECT CAST('1020' AS TIME) +-- GO + +SELECT CAST('10202' AS TIME) +GO + +-- need handling +-- SELECT CAST('102022' AS TIME) +-- GO + +SELECT CAST('1010101' AS TIME) +GO + +-- need handling +-- SELECT CAST('10101010' AS TIME) +-- GO + +SELECT CAST('101010101' AS TIME) +GO + +SELECT CAST('01 Am' AS TIME) +GO + +SELECT CAST('Am 01' AS TIME) +GO + +SELECT CAST('13 Am' AS TIME) +GO + +SELECT CAST('01 Pm' AS TIME) +GO + +SELECT CAST('24 Pm' AS TIME) +GO + +SELECT CAST('11:58:59 Pm' AS TIME) +GO + +SELECT CAST('2000-11-23 Am' AS TIME) +GO + +SELECT CAST('2000-11-23 11:58:59 Pm' AS TIME) +GO + +-- different kind of input +SELECT CAST('1998-02-23T14:23:05' AS time) +GO + +SELECT CAST('1998-02-23num14:23:05' AS time) GO SELECT CAST('12 jan 20 2:3' AS TIME) @@ -228,9 +340,6 @@ GO SELECT CAST('2012jan01' AS TIME) GO -SELECT CAST('20121201' AS TIME) -GO - SELECT CAST('Jan 2021 010506.289' AS TIME) GO From 8438f2a48766c3f4fd0d2822d8d1e5670f4d4ceb Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Thu, 28 Sep 2023 05:53:39 +0000 Subject: [PATCH 08/27] Implemented to-do parts and formatting --- contrib/babelfishpg_tsql/src/hooks.c | 210 ++++++++++----- test/JDBC/expected/babel_time-vu-verify.out | 276 ++++++++++++-------- test/JDBC/input/babel_time-vu-verify.mix | 109 ++++---- 3 files changed, 371 insertions(+), 224 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 86e2163434..020014f324 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -141,8 +141,8 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, const char *queryString, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); -static void gen_func_time_in_error(); -static bool containsInMonthFormat(int *ftype); +static bool isTextMonthPresent(char* field); +static bool containsInTextMonthFormat(int *ftype, char **field); static Datum pltsql_time_in(const char *str, int32 typmod); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, @@ -230,7 +230,7 @@ static table_variable_satisfies_update_hook_type prev_table_variable_satisfies_u static table_variable_satisfies_vacuum_hook_type prev_table_variable_satisfies_vacuum = NULL; static table_variable_satisfies_vacuum_horizon_hook_type prev_table_variable_satisfies_vacuum_horizon = NULL; static drop_relation_refcnt_hook_type prev_drop_relation_refcnt_hook = NULL; -static time_in_hook_type prev_time_in_hook = NULL; +static tsql_time_in_hook_type prev_tsql_time_in_hook = NULL; /***************************************** * Install / Uninstall @@ -392,8 +392,8 @@ InstallExtendedHooks(void) prev_drop_relation_refcnt_hook = drop_relation_refcnt_hook; drop_relation_refcnt_hook = pltsql_drop_relation_refcnt_hook; - prev_time_in_hook = time_in_hook; - time_in_hook = pltsql_time_in; + prev_tsql_time_in_hook = tsql_time_in_hook; + tsql_time_in_hook = pltsql_time_in; select_common_type_hook = select_common_type_for_isnull; } @@ -458,7 +458,7 @@ UninstallExtendedHooks(void) IsToastRelationHook = PrevIsToastRelationHook; IsToastClassHook = PrevIsToastClassHook; drop_relation_refcnt_hook = prev_drop_relation_refcnt_hook; - time_in_hook = prev_time_in_hook; + tsql_time_in_hook = prev_tsql_time_in_hook; } /***************************************** @@ -2699,30 +2699,61 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume return (total_digit_count > TDS_NUMERIC_MAX_PRECISION); } -/* - * Throw a common error message while casting to time datatype - */ -static void gen_func_time_in_error() +/* Checks whether the field is valid text month */ +static bool isTextMonthPresent(char* field) { - ereport(ERROR, - (errcode(ERRCODE_INVALID_DATETIME_FORMAT), - errmsg("Conversion failed when converting date and/or time from character string."))); + char* months[] = {"january", "february", "march", "april", "may", + "june", "july", "august", "september", "october", + "november", "december", "jan", "feb", "mar", "apr", + "may", "jun", "jul", "aug", "sep", "oct", "nov", "dec"}; + for(int i = 0; i < 24; i++) + if(pg_strcasecmp(field, months[i]) == 0) + return true; + return false; } -static bool containsInMonthFormat(int *ftype){ - int count0 = 0, count1 = 0; - for(int i=0;i<3;i++) +/* + * This function will check whether the first 3 inputs are in any of the format + * `DD MON YYY`, `DD YYYY MON`, `MON DD YYYY`, `MON YYYY DD`, `YYYY MM DD`, `YYYY DD MM` + * where MON is month in text format then returns true if present. + */ +static bool containsInTextMonthFormat(int *ftype, char **field){ + int count_number = 0, count_string = 0; + for(int i = 0; i < 3; i++) { if(ftype[i] == DTK_NUMBER) - count0++; + count_number++; else if(ftype[i] == DTK_STRING) - /* To-Do Check if valid text month is given */ - count1++; + { + /* Check whether the string is valid text month */ + if(!isTextMonthPresent(field[i])) + return false; + count_string++; + } else return false; } - if(count0 ==2 && count1 ==1) + if(count_number == 2 && count_string == 1) + { + /* + * If the first field is an string then swap with the second field + * as when the date is given separatly then all different forms of + * dates is supported. To avoid the conversion failure from `isTextMonthPresent` + * later we are swapping earlier. + */ + if(ftype[0] == DTK_STRING) + { + char* temp_field; + int temp_ftype; + temp_field = field[0]; + temp_ftype = ftype[0]; + field[0] = field[1]; + field[1] = temp_field; + ftype[0] = ftype[1]; + ftype[1] = temp_ftype; + } return true; + } return false; } @@ -2739,29 +2770,41 @@ Datum pltsql_time_in(const char *str, int32 typmod) char *field[MAXDATEFIELDS]; int dtype; int ftype[MAXDATEFIELDS]; - StringInfo sf_1 ; + StringInfo res ; int status; + /* Throw a common error message while casting to time datatype */ + #define TIME_IN_ERROR() \ + ereport(ERROR, \ + (errcode(ERRCODE_INVALID_DATETIME_FORMAT), \ + errmsg("Conversion failed when converting date and/or time from character string."))); \ + dterr = ParseDateTime(str, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) { if(nf >= 3) { - if(containsInMonthFormat(ftype)) + /* + * If the input is of format "YYYY MON DD", then convert + * to format of YYYY-MON-DD and ftype changes to "DTK_DATE" + */ + if(containsInTextMonthFormat(ftype, field)) { - StringInfoData buf; - initStringInfo(&buf); - appendStringInfoString(&buf, field[0]); - for(int i=1;i<3;i++) - { - appendStringInfoString(&buf, "-"); - appendStringInfoString(&buf, field[i]); - - } - field[0]=buf.data; + /* + * For example if input is "2000 nov 23" will be converted + * to "2000-nov-23". + */ + res = makeStringInfo(); + appendStringInfo(res, "%s-%s-%s", field[0], field[1], field[2]); + field[0] = NULL; + field[0] = res->data; ftype[0] = DTK_DATE; nf = nf - 2; + /* + * Since the first 3 fields converted to 1, + * skip the attached fields. + */ for(int i = 1; i < nf; i++) { field[i] = field[i+2]; @@ -2770,70 +2813,112 @@ Datum pltsql_time_in(const char *str, int32 typmod) } } - for(int i=0;i < nf; i++) + for(int i = 0; i < nf; i++) { + char *temp_field; + int len; + char* different_date_formats[] = {"/", ".", "-"}; + temp_field = pstrdup(field[i]); + len = strlen(temp_field); switch(ftype[i]) { case DTK_NUMBER: - switch(strlen(field[i])) + switch(len) { case 1: case 2: /* - * At this point the 1,2 digit number should be considered as - * time only if there is an [AP]M after the number or else + * At this point the digit number of length 1,2 should be considered as + * time only if there is an [ap]m after the number or else * should throw an error */ - if(i == nf-1 || ftype[i+1] != DTK_STRING) - { - gen_func_time_in_error(); - } - status = RE_compile_and_execute(cstring_to_text("^([AP]M)$"), + if(i == nf - 1 || ftype[i+1] != DTK_STRING) + TIME_IN_ERROR(); + status = RE_compile_and_execute(cstring_to_text("^([ap]m)$"), (char *) field[i+1], strlen(field[i+1]), - REG_ADVANCED | REG_ICASE, DEFAULT_COLLATION_OID, + REG_ADVANCED, DEFAULT_COLLATION_OID, 0, NULL); if(!status) - gen_func_time_in_error(); - - sf_1 = makeStringInfo(); - appendStringInfo(sf_1, "%s%s", field[i], ":0:0"); - field[i] = sf_1->data; + TIME_IN_ERROR(); + /* + * For example if the input is "1 am" + * will be converted to "1:00:00 am". + */ + res = makeStringInfo(); + appendStringInfo(res, "%s%s", field[i], ":00:00"); + field[i] = NULL; + field[i] = res->data; ftype[i] = DTK_TIME; break; - /* - * To-Do - * Case 6,8 needs special handling to convert the - * given numeric to date format(YYYY-MM-DD/YY-MM-DD) - */ + case 4: + /* + * If the numeric input is of length 4, then convert + * to year with default format of YYYY-01-01. + * For example if input is "2000" will be converted + * to "2000-01-01". + */ + res = makeStringInfo(); + appendStringInfo(res, "%s%s", field[i], "-01-01"); + field[i] = NULL; + field[i] = res->data; + ftype[i] = DTK_DATE; + break; + case 6: case 8: + res = makeStringInfo(); + for(int k = 0; k < len; k++) + { + appendStringInfo(res, "%c", temp_field[k]); + if((len == 6 && ((k + 1) % 2 == 0 && k < 5)) || + (len == 8 && (k == 3 || k == 5))) + appendStringInfo(res, "%c", '-'); + } + field[i] = NULL; + field[i] = res->data; + ftype[i] = DTK_DATE; break; /* * If the numeric is of length {3,5,7, >8} then an error should be thrown*/ default: - gen_func_time_in_error(); + TIME_IN_ERROR(); + } + break; + + case DTK_DATE: + /* + * If the input is of format `Mon{/.-}yyyy{/.-}dd` or `Mon{/.-}dd{/.-}yyyy + * shouldn't be supported. + * Supported date formats are `Mon yyyy dd`, `Mon dd yyyy`, `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` + */ + for(int k = 0 ; k < 3; k++) + { + temp_field = strtok(temp_field, different_date_formats[k]); + if (pg_strcasecmp(field[i], temp_field) != 0) break; } + if(isTextMonthPresent(temp_field)) + TIME_IN_ERROR(); + break; + + default: + break; } + pfree(temp_field); } switch(nf) { case 1: - /* - * To-Do - * If the input is of format `Mon{/.}yyyy{/.}dd` or `Mon{/.}dd{/.}yyyy - * shouldn't be supported. - */ /* * If only date is specified add an default time of - * 0:0:0 + * 00:00:00 */ if(ftype[0] == DTK_DATE) { ftype[1] = DTK_TIME; - field[1] = "0:0:0"; - nf = nf+1; + field[1] = "00:00:00"; + nf = nf + 1; } break; case 3: @@ -2853,8 +2938,9 @@ Datum pltsql_time_in(const char *str, int32 typmod) dterr = DecodeTimeOnly(field, ftype, nf, &dtype, tm, &fsec, &tz); } + if (dterr != 0) - gen_func_time_in_error(); + TIME_IN_ERROR(); tm2time(tm, fsec, &result); AdjustTimeForTypmod(&result, typmod); diff --git a/test/JDBC/expected/babel_time-vu-verify.out b/test/JDBC/expected/babel_time-vu-verify.out index f3c17f7dce..c83235e488 100644 --- a/test/JDBC/expected/babel_time-vu-verify.out +++ b/test/JDBC/expected/babel_time-vu-verify.out @@ -12,7 +12,7 @@ GO -- tsql -- if only date is given as input -- accepted formats are `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` --- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` +-- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd`, Mon yyyy dd`, `Mon dd yyyy` SELECT CAST(' 23 - 11 - 2000 ' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -116,22 +116,18 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- Need handling(was failing in SQL Server) SELECT CAST('Nov-2000-23' AS TIME) GO -~~START~~ -time -00:00:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- Need handling(was failing in SQL Server) SELECT CAST('Nov-23-2000' AS TIME) GO -~~START~~ -time -00:00:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT CAST('2000-Nov-23' AS TIME) @@ -164,22 +160,18 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- Need handling(was failing in SQL Server) SELECT CAST('Nov/2000/23' AS TIME) GO -~~START~~ -time -00:00:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- Need handling(was failing in SQL Server) SELECT CAST('Nov/23/2000' AS TIME) GO -~~START~~ -time -00:00:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT CAST('2000/Nov/23' AS TIME) @@ -256,17 +248,36 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- Need handling(was failing in SQL Server) SELECT CAST('Nov.2000.23' AS TIME) GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Nov.23.2000' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('2000.Nov.23' AS TIME) +GO ~~START~~ time 00:00:00.0000000 ~~END~~ --- Need handling(was failing in SQL Server) -SELECT CAST('Nov.23.2000' AS TIME) +SELECT CAST('2000.23.Nov' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('jan 12 20 ' AS TIME) GO ~~START~~ time @@ -274,7 +285,7 @@ time ~~END~~ -SELECT CAST('2000.Nov.23' AS TIME) +SELECT CAST('jan 2012 12 ' AS TIME) GO ~~START~~ time @@ -282,7 +293,76 @@ time ~~END~~ -SELECT CAST('2000.23.Nov' AS TIME) +SELECT CAST('jan 12 2002 ' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 March 12 ' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('2012 12 September' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('12 JuLy 2002 ' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('12 2002 AprIl' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('12 decemBer 20 ' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + + +SELECT CAST('Jan-01-2001' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Jan-2021-01' AS TIME) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -312,10 +392,14 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +SELECT CAST('1020' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + --- need handling --- SELECT CAST('1020' AS TIME) --- GO SELECT CAST('10202' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -323,10 +407,14 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +SELECT CAST('101022' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + --- need handling --- SELECT CAST('102022' AS TIME) --- GO SELECT CAST('1010101' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -334,10 +422,14 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ +SELECT CAST('10101010' AS TIME) +GO +~~START~~ +time +00:00:00.0000000 +~~END~~ + --- need handling --- SELECT CAST('10101010' AS TIME) --- GO SELECT CAST('101010101' AS TIME) GO ~~ERROR (Code: 33557097)~~ @@ -405,54 +497,66 @@ time ~~END~~ --- different kind of input -SELECT CAST('1998-02-23T14:23:05' AS time) +SELECT CAST('1020 2:3' AS TIME) GO ~~START~~ time -14:23:05.0000000 +02:03:00.0000000 ~~END~~ -SELECT CAST('1998-02-23num14:23:05' AS time) +SELECT CAST('1020 2:3 Pm' AS TIME) +GO +~~START~~ +time +14:03:00.0000000 +~~END~~ + + +SELECT CAST('1020 Pm' AS TIME) GO ~~ERROR (Code: 33557097)~~ ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('12 jan 20 2:3' AS TIME) +SELECT CAST('1020 Pm 2:3' AS TIME) GO -~~START~~ -time -02:03:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('12 decemBer 20 2:3' AS TIME) +SELECT CAST('001200' AS TIME) GO -~~START~~ -time -02:03:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('jan 12 20 2:3' AS TIME) +SELECT CAST('Jan-2021-01 121200 ' AS TIME) GO -~~START~~ -time -02:03:00.0000000 -~~END~~ +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ -SELECT CAST('jan 2012 12 2:3' AS TIME) +-- different kind of input +SELECT CAST('1998-02-23T14:23:05' AS time) GO ~~START~~ time -02:03:00.0000000 +14:23:05.0000000 ~~END~~ +SELECT CAST('1998-02-23num14:23:05' AS time) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ + + -- casting to particular round off, valid in range of [0-7] SELECT CAST('2015-03-19 01:05:06.289' AS TIME(0)) GO @@ -681,39 +785,6 @@ time ~~END~~ --- case for different types of date format(mm-dd-yyyy, mm-yyyy-dd) -SELECT CAST('Jan-01-2001' AS TIME) -GO -~~START~~ -time -00:00:00.0000000 -~~END~~ - - -SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) -GO -~~START~~ -time -01:05:06.2890000 -~~END~~ - - -SELECT CAST('Jan-2021-01' AS TIME) -GO -~~START~~ -time -00:00:00.0000000 -~~END~~ - - -SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) -GO -~~START~~ -time -01:05:06.2890000 -~~END~~ - - -- case where input is of format 'mm yyyy dd hhmmss.ss' SELECT CAST('Jan 2021 01 010506.289' AS TIME) GO @@ -722,23 +793,6 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- if input is given in hhmmss -SELECT CAST('121200' AS TIME) -GO -~~START~~ -time -12:12:00.0000000 -~~END~~ - - -SELECT CAST('001200' AS TIME) -GO -~~START~~ -time -00:12:00.0000000 -~~END~~ - - SELECT CAST('0012:00' AS TIME) GO ~~START~~ @@ -877,19 +931,11 @@ GO ~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ --- need to check -SELECT CAST('Jan-2021-01 121200 ' AS TIME) -GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ - - SELECT CAST('Jan-2021-01 121200 -1' AS TIME) GO ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: time zone "jan-2021-01" not recognized)~~ +~~ERROR (Message: Conversion failed when converting date and/or time from character string.)~~ SELECT * from babel_TIME_vu_prepare_t1 diff --git a/test/JDBC/input/babel_time-vu-verify.mix b/test/JDBC/input/babel_time-vu-verify.mix index acda83f09d..894acd2fce 100644 --- a/test/JDBC/input/babel_time-vu-verify.mix +++ b/test/JDBC/input/babel_time-vu-verify.mix @@ -1,6 +1,12 @@ +-- psql +-- behaviour of casting to time in psql +SELECT CAST('2012-02-23' AS TIME) +GO + +-- tsql -- if only date is given as input -- accepted formats are `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` --- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` +-- If text month is given then acceptable formats are `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd`, Mon yyyy dd`, `Mon dd yyyy` SELECT CAST(' 23 - 11 - 2000 ' AS TIME) GO @@ -43,11 +49,9 @@ GO SELECT CAST('23-2000-Nov' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov-2000-23' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov-23-2000' AS TIME) GO @@ -63,11 +67,9 @@ GO SELECT CAST('23/2000/Nov' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov/2000/23' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov/23/2000' AS TIME) GO @@ -101,11 +103,9 @@ GO SELECT CAST('23.2000.Nov' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov.2000.23' AS TIME) GO --- Need handling(was failing in SQL Server) SELECT CAST('Nov.23.2000' AS TIME) GO @@ -115,6 +115,42 @@ GO SELECT CAST('2000.23.Nov' AS TIME) GO +SELECT CAST('jan 12 20 ' AS TIME) +GO + +SELECT CAST('jan 2012 12 ' AS TIME) +GO + +SELECT CAST('jan 12 2002 ' AS TIME) +GO + +SELECT CAST('2012 March 12 ' AS TIME) +GO + +SELECT CAST('2012 12 September' AS TIME) +GO + +SELECT CAST('12 JuLy 2002 ' AS TIME) +GO + +SELECT CAST('12 2002 AprIl' AS TIME) +GO + +SELECT CAST('12 decemBer 20 ' AS TIME) +GO + +SELECT CAST('Jan-01-2001' AS TIME) +GO + +SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) +GO + +SELECT CAST('Jan-2021-01' AS TIME) +GO + +SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) +GO + -- If numeric is specified -- If `am` or `pm` is specified SELECT CAST('1' AS TIME) @@ -126,23 +162,20 @@ GO SELECT CAST('102' AS TIME) GO --- need handling --- SELECT CAST('1020' AS TIME) --- GO +SELECT CAST('1020' AS TIME) +GO SELECT CAST('10202' AS TIME) GO --- need handling --- SELECT CAST('102022' AS TIME) --- GO +SELECT CAST('101022' AS TIME) +GO SELECT CAST('1010101' AS TIME) GO --- need handling --- SELECT CAST('10101010' AS TIME) --- GO +SELECT CAST('10101010' AS TIME) +GO SELECT CAST('101010101' AS TIME) GO @@ -171,23 +204,29 @@ GO SELECT CAST('2000-11-23 11:58:59 Pm' AS TIME) GO --- different kind of input -SELECT CAST('1998-02-23T14:23:05' AS time) +SELECT CAST('1020 2:3' AS TIME) GO -SELECT CAST('1998-02-23num14:23:05' AS time) +SELECT CAST('1020 2:3 Pm' AS TIME) +GO + +SELECT CAST('1020 Pm' AS TIME) +GO + +SELECT CAST('1020 Pm 2:3' AS TIME) GO -SELECT CAST('12 jan 20 2:3' AS TIME) +SELECT CAST('001200' AS TIME) GO -SELECT CAST('12 decemBer 20 2:3' AS TIME) +SELECT CAST('Jan-2021-01 121200 ' AS TIME) GO -SELECT CAST('jan 12 20 2:3' AS TIME) +-- different kind of input +SELECT CAST('1998-02-23T14:23:05' AS time) GO -SELECT CAST('jan 2012 12 2:3' AS TIME) +SELECT CAST('1998-02-23num14:23:05' AS time) GO -- casting to particular round off, valid in range of [0-7] @@ -278,30 +317,10 @@ GO SELECT CAST('2012 - FeB - 23 2 : 3 : 8 . 876 - 8' AS TIME(0)) GO --- case for different types of date format(mm-dd-yyyy, mm-yyyy-dd) -SELECT CAST('Jan-01-2001' AS TIME) -GO - -SELECT CAST('Jan-01-2001 01:05:06.289' AS TIME) -GO - -SELECT CAST('Jan-2021-01' AS TIME) -GO - -SELECT CAST('Jan-2021-01 01:05:06.289' AS TIME) -GO - -- case where input is of format 'mm yyyy dd hhmmss.ss' SELECT CAST('Jan 2021 01 010506.289' AS TIME) GO --- if input is given in hhmmss -SELECT CAST('121200' AS TIME) -GO - -SELECT CAST('001200' AS TIME) -GO - SELECT CAST('0012:00' AS TIME) GO @@ -366,10 +385,6 @@ GO SELECT CAST('0-0-00' AS TIME) GO --- need to check -SELECT CAST('Jan-2021-01 121200 ' AS TIME) -GO - SELECT CAST('Jan-2021-01 121200 -1' AS TIME) GO From 95f935e1b50125b3006451dc61e8f49604b28448 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Thu, 28 Sep 2023 06:21:52 +0000 Subject: [PATCH 09/27] Empty commit From 83c5c9ba58dca111d5ea6d4147c8b283a5a3a360 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Thu, 28 Sep 2023 06:48:49 +0000 Subject: [PATCH 10/27] Remove additional changes came when merging --- contrib/babelfishpg_tsql/src/hooks.c | 2 -- 1 file changed, 2 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index a2acbaf074..9e4884786c 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -394,8 +394,6 @@ InstallExtendedHooks(void) prev_tsql_time_in_hook = tsql_time_in_hook; tsql_time_in_hook = pltsql_time_in; - - select_common_type_hook = select_common_type_for_isnull; } void From 9d9e3bca0506c65931e4d0b88774faed777ddecf Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Wed, 4 Oct 2023 06:41:14 +0000 Subject: [PATCH 11/27] Modified the formatting and comments --- contrib/babelfishpg_tsql/src/hooks.c | 117 +++++++++++++++------------ 1 file changed, 65 insertions(+), 52 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 9e4884786c..d3ce924272 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -144,7 +144,7 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, ParamListInfo params, QueryCompletion *qc); static bool isTextMonthPresent(char* field); static bool containsInTextMonthFormat(int *ftype, char **field); -static Datum pltsql_time_in(const char *str, int32 typmod); +static bool pltsql_time_in(const char *str, int32 typmod, TimeADT *result); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, QueryEnvironment *queryEnv, ParamListInfo params, QueryCompletion *qc); @@ -2837,23 +2837,23 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume static bool isTextMonthPresent(char* field) { char* months[] = {"january", "february", "march", "april", "may", - "june", "july", "august", "september", "october", - "november", "december", "jan", "feb", "mar", "apr", - "may", "jun", "jul", "aug", "sep", "oct", "nov", "dec"}; - for(int i = 0; i < 24; i++) - if(pg_strcasecmp(field, months[i]) == 0) + "june", "july", "august", "september", "october", + "november", "december", "jan", "feb", "mar", "apr", + "may", "jun", "jul", "aug", "sep", "oct", "nov", "dec"}; + for (int i = 0; i < 24; i++) + if (pg_strcasecmp(field, months[i]) == 0) return true; return false; } /* * This function will check whether the first 3 inputs are in any of the format - * `DD MON YYY`, `DD YYYY MON`, `MON DD YYYY`, `MON YYYY DD`, `YYYY MM DD`, `YYYY DD MM` + * `DD MON YYY`, `DD YYYY MON`, `MON DD YYYY`, `MON YYYY DD`, `YYYY MON DD`, `YYYY DD MON` * where MON is month in text format then returns true if present. */ static bool containsInTextMonthFormat(int *ftype, char **field){ int count_number = 0, count_string = 0; - for(int i = 0; i < 3; i++) + for (int i = 0; i < 3; i++) { if(ftype[i] == DTK_NUMBER) count_number++; @@ -2867,15 +2867,17 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ else return false; } - if(count_number == 2 && count_string == 1) + if (count_number == 2 && count_string == 1) { /* * If the first field is an string then swap with the second field * as when the date is given separatly then all different forms of * dates is supported. To avoid the conversion failure from `isTextMonthPresent` * later we are swapping earlier. + * + * For example convert the input from "JULY-23-2000" to "23-JULY-2000" */ - if(ftype[0] == DTK_STRING) + if (ftype[0] == DTK_STRING) { char* temp_field; int temp_ftype; @@ -2891,9 +2893,16 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ return false; } -Datum pltsql_time_in(const char *str, int32 typmod) +/* + * pltsql_time_in + * The function modifies the given input into valid form and + * stores the output to result. + * Returns + * false - If the sql_dialect is not an TSQL + * true - If the sql_dialect is an TSQL + */ +bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) { - TimeADT result; fsec_t fsec; struct pg_tm tt, *tm = &tt; @@ -2907,23 +2916,28 @@ Datum pltsql_time_in(const char *str, int32 typmod) StringInfo res ; int status; + if (sql_dialect != SQL_DIALECT_TSQL) + return false; + /* Throw a common error message while casting to time datatype */ #define TIME_IN_ERROR() \ ereport(ERROR, \ - (errcode(ERRCODE_INVALID_DATETIME_FORMAT), \ - errmsg("Conversion failed when converting date and/or time from character string."))); \ + (errcode(ERRCODE_INVALID_DATETIME_FORMAT), \ + errmsg("Conversion failed when converting date and/or time from character string."))); \ dterr = ParseDateTime(str, workbuf, sizeof(workbuf), - field, ftype, MAXDATEFIELDS, &nf); + field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) { - if(nf >= 3) + if (nf >= 3) { /* - * If the input is of format "YYYY MON DD", then convert - * to format of YYYY-MON-DD and ftype changes to "DTK_DATE" + * If the input is of format `DD MON YYY`, `DD YYYY MON`, `MON DD YYYY`, + * `MON YYYY DD`, `YYYY MON DD`, `YYYY DD MON`, then convert + * to format of `DD MON YYY`, `DD YYYY MON`, `YYYY MON DD`, `YYYY DD MON` + * and ftype changes to "DTK_DATE" */ - if(containsInTextMonthFormat(ftype, field)) + if (containsInTextMonthFormat(ftype, field)) { /* * For example if input is "2000 nov 23" will be converted @@ -2931,7 +2945,6 @@ Datum pltsql_time_in(const char *str, int32 typmod) */ res = makeStringInfo(); appendStringInfo(res, "%s-%s-%s", field[0], field[1], field[2]); - field[0] = NULL; field[0] = res->data; ftype[0] = DTK_DATE; nf = nf - 2; @@ -2947,17 +2960,17 @@ Datum pltsql_time_in(const char *str, int32 typmod) } } - for(int i = 0; i < nf; i++) + for (int i = 0; i < nf; i++) { char *temp_field; int len; char* different_date_formats[] = {"/", ".", "-"}; temp_field = pstrdup(field[i]); len = strlen(temp_field); - switch(ftype[i]) + switch (ftype[i]) { case DTK_NUMBER: - switch(len) + switch (len) { case 1: case 2: @@ -2966,23 +2979,21 @@ Datum pltsql_time_in(const char *str, int32 typmod) * time only if there is an [ap]m after the number or else * should throw an error */ - if(i == nf - 1 || ftype[i+1] != DTK_STRING) - TIME_IN_ERROR(); - status = RE_compile_and_execute(cstring_to_text("^([ap]m)$"), - (char *) field[i+1], strlen(field[i+1]), - REG_ADVANCED, DEFAULT_COLLATION_OID, - 0, NULL); - if(!status) + if (i == nf - 1 || ftype[i+1] != DTK_STRING) TIME_IN_ERROR(); /* * For example if the input is "1 am" * will be converted to "1:00:00 am". */ - res = makeStringInfo(); - appendStringInfo(res, "%s%s", field[i], ":00:00"); - field[i] = NULL; - field[i] = res->data; - ftype[i] = DTK_TIME; + if (pg_strcasecmp(field[i+1], "am") == 0 || pg_strcasecmp(field[i+1], "pm") == 0) + { + res = makeStringInfo(); + appendStringInfo(res, "%s%s", field[i], ":00:00"); + field[i] = res->data; + ftype[i] = DTK_TIME; + } + else + TIME_IN_ERROR(); break; case 4: @@ -2994,7 +3005,6 @@ Datum pltsql_time_in(const char *str, int32 typmod) */ res = makeStringInfo(); appendStringInfo(res, "%s%s", field[i], "-01-01"); - field[i] = NULL; field[i] = res->data; ftype[i] = DTK_DATE; break; @@ -3002,19 +3012,19 @@ Datum pltsql_time_in(const char *str, int32 typmod) case 6: case 8: res = makeStringInfo(); - for(int k = 0; k < len; k++) + for (int k = 0; k < len; k++) { appendStringInfo(res, "%c", temp_field[k]); if((len == 6 && ((k + 1) % 2 == 0 && k < 5)) || - (len == 8 && (k == 3 || k == 5))) - appendStringInfo(res, "%c", '-'); + (len == 8 && (k == 3 || k == 5))) + appendStringInfo(res, "%c", '-'); } - field[i] = NULL; field[i] = res->data; ftype[i] = DTK_DATE; break; /* - * If the numeric is of length {3,5,7, >8} then an error should be thrown*/ + * If the numeric is of length {3,5,7, >8} then an error should be thrown + */ default: TIME_IN_ERROR(); } @@ -3024,15 +3034,17 @@ Datum pltsql_time_in(const char *str, int32 typmod) /* * If the input is of format `Mon{/.-}yyyy{/.-}dd` or `Mon{/.-}dd{/.-}yyyy * shouldn't be supported. - * Supported date formats are `Mon yyyy dd`, `Mon dd yyyy`, `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` + * Supported date formats are `Mon yyyy dd`, `Mon dd yyyy`, + * `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd`, + * `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` */ - for(int k = 0 ; k < 3; k++) + for (int k = 0 ; k < 3; k++) { temp_field = strtok(temp_field, different_date_formats[k]); if (pg_strcasecmp(field[i], temp_field) != 0) break; } - if(isTextMonthPresent(temp_field)) + if (isTextMonthPresent(temp_field)) TIME_IN_ERROR(); break; @@ -3041,26 +3053,27 @@ Datum pltsql_time_in(const char *str, int32 typmod) } pfree(temp_field); } - switch(nf) + switch (nf) { case 1: /* - * If only date is specified add an default time of - * 00:00:00 + * If only date is specified then add an default + * time of 00:00:00 */ - if(ftype[0] == DTK_DATE) + if (ftype[0] == DTK_DATE) { ftype[1] = DTK_TIME; field[1] = "00:00:00"; nf = nf + 1; } break; + case 3: /* * If the given input is of format `yyyy-mm-ddThh:mm:ss` * then conver it to `yyyy-mm-dd hh:mm:ss` by ignoring 'T' */ - if(ftype[1] == DTK_STRING && pg_strcasecmp(field[1], "t") == 0 && ftype[2] == DTK_TIME) + if (ftype[1] == DTK_STRING && pg_strcasecmp(field[1], "t") == 0 && ftype[2] == DTK_TIME) { ftype[1] = ftype[2]; field[1] = field[2]; @@ -3076,10 +3089,10 @@ Datum pltsql_time_in(const char *str, int32 typmod) if (dterr != 0) TIME_IN_ERROR(); - tm2time(tm, fsec, &result); - AdjustTimeForTypmod(&result, typmod); + tm2time(tm, fsec, result); + AdjustTimeForTypmod(result, typmod); - PG_RETURN_TIMEADT(result); + return true; } /* From 1be81a14313e5f5a79529617ced0a0a069009630 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Wed, 4 Oct 2023 07:37:02 +0000 Subject: [PATCH 12/27] Removed unused variables --- contrib/babelfishpg_tsql/src/hooks.c | 1 - 1 file changed, 1 deletion(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 43cb1c85cd..8b7774b486 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -2921,7 +2921,6 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) int dtype; int ftype[MAXDATEFIELDS]; StringInfo res ; - int status; if (sql_dialect != SQL_DIALECT_TSQL) return false; From 4e77880463f59706e9c8a367244698634d96b141 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Thu, 5 Oct 2023 05:04:52 +0000 Subject: [PATCH 13/27] Added comments for code --- contrib/babelfishpg_tsql/src/hooks.c | 38 ++++++++++++++++++++-------- 1 file changed, 28 insertions(+), 10 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 8b7774b486..befbb9a124 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -142,7 +142,7 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, const char *queryString, ProcessUtilityContext context, ParamListInfo params, QueryCompletion *qc); -static bool isTextMonthPresent(char* field); +static bool isValidTextMonth(char* field); static bool containsInTextMonthFormat(int *ftype, char **field); static bool pltsql_time_in(const char *str, int32 typmod, TimeADT *result); static void pltsql_bbfSelectIntoAddIdentity(IntoClause *into, List *tableElts); @@ -2841,7 +2841,7 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume } /* Checks whether the field is valid text month */ -static bool isTextMonthPresent(char* field) +static bool isValidTextMonth(char* field) { char* months[] = {"january", "february", "march", "april", "may", "june", "july", "august", "september", "october", @@ -2867,7 +2867,7 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ else if(ftype[i] == DTK_STRING) { /* Check whether the string is valid text month */ - if(!isTextMonthPresent(field[i])) + if(!isValidTextMonth(field[i])) return false; count_string++; } @@ -2879,7 +2879,7 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ /* * If the first field is an string then swap with the second field * as when the date is given separatly then all different forms of - * dates is supported. To avoid the conversion failure from `isTextMonthPresent` + * dates is supported. To avoid the conversion failure from `isValidTextMonth` * later we are swapping earlier. * * For example convert the input from "JULY-23-2000" to "23-JULY-2000" @@ -2976,6 +2976,15 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) switch (ftype[i]) { case DTK_NUMBER: + /* If only number fields are present in + * the input then following considerations should + * be followed. + * 1. len = 1,2 : Time and [ap]m should be specified + * 2. len = 4 : Considered as year with format "YYYY-01-01" + * 3. len = 6 : Considered as format `"YYMMDD" + * 4. len = 8 : Considered as format "YYYYMMDD" + * 5. len = 3,5,7,>8 : Not an valid and should throw error + */ switch (len) { case 1: @@ -3017,6 +3026,11 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) case 6: case 8: + /* + * For example if input is "201213" will be converted + * to "2000-12-13", and input "20001118" will be + * converted to "2000-11-18" + */ res = makeStringInfo(); for (int k = 0; k < len; k++) { @@ -3028,9 +3042,7 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) field[i] = res->data; ftype[i] = DTK_DATE; break; - /* - * If the numeric is of length {3,5,7, >8} then an error should be thrown - */ + default: TIME_IN_ERROR(); } @@ -3039,10 +3051,11 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) case DTK_DATE: /* * If the input is of format `Mon{/.-}yyyy{/.-}dd` or `Mon{/.-}dd{/.-}yyyy + * "DD MM YYYY", "DD YYYY MM", "MM YYYY DD", "MM DD YYYY", "YYYY DD MM", + * "YYYY MM DD", "DD{/.-}MM{/.-}YYYY", "DD{/.-}YYYY{/.-}DD" * shouldn't be supported. * Supported date formats are `Mon yyyy dd`, `Mon dd yyyy`, - * `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd`, - * `dd{-/.}Mon{-/.}yyyy`, `yyyy{-/.}Mon{-/.}dd` + * `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` */ for (int k = 0 ; k < 3; k++) { @@ -3050,7 +3063,12 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) if (pg_strcasecmp(field[i], temp_field) != 0) break; } - if (isTextMonthPresent(temp_field)) + /* + * If text month is present in start of field like + * `Mon{/.-}yyyy{/.-}dd` or `Mon{/.-}dd{/.-}yyyy then + * an error should be thrown + */ + if (isValidTextMonth(temp_field)) TIME_IN_ERROR(); break; From a3173050f14e30edf6d4b26274c279a93e27c966 Mon Sep 17 00:00:00 2001 From: vasavi suthapalli Date: Wed, 11 Oct 2023 10:43:51 +0000 Subject: [PATCH 14/27] Formatting fixes and new fixes implementation for offset --- contrib/babelfishpg_tsql/src/hooks.c | 165 ++++-- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 31 -- test/JDBC/expected/babel_time-vu-prepare.out | 5 + test/JDBC/expected/babel_time-vu-verify.out | 497 +++++++++++++++++-- test/JDBC/input/babel_time-vu-prepare.sql | 3 + test/JDBC/input/babel_time-vu-verify.mix | 176 ++++++- 6 files changed, 761 insertions(+), 116 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index d37a4c9d02..db3ef81a0d 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -2841,7 +2841,7 @@ pltsql_detect_numeric_overflow(int weight, int dscale, int first_block, int nume } /* Checks whether the field is valid text month */ -static bool isValidTextMonth(char* field) +static bool isTextMonthPresent(char* field) { char* months[] = {"january", "february", "march", "april", "may", "june", "july", "august", "september", "october", @@ -2862,12 +2862,12 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ int count_number = 0, count_string = 0; for (int i = 0; i < 3; i++) { - if(ftype[i] == DTK_NUMBER) + if (ftype[i] == DTK_NUMBER) count_number++; - else if(ftype[i] == DTK_STRING) + else if (ftype[i] == DTK_STRING) { /* Check whether the string is valid text month */ - if(!isValidTextMonth(field[i])) + if (!isTextMonthPresent(field[i])) return false; count_string++; } @@ -2879,10 +2879,10 @@ static bool containsInTextMonthFormat(int *ftype, char **field){ /* * If the first field is an string then swap with the second field * as when the date is given separatly then all different forms of - * dates is supported. To avoid the conversion failure from `isValidTextMonth` + * dates is supported. To avoid the conversion failure from `isTextMonthPresent` * later we are swapping earlier. * - * For example convert the input from "JULY-23-2000" to "23-JULY-2000" + * For example convert the input from "JULY 23 2000" to "23 JULY 2000" */ if (ftype[0] == DTK_STRING) { @@ -2920,8 +2920,15 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) char *field[MAXDATEFIELDS]; int dtype; int ftype[MAXDATEFIELDS]; - StringInfo res ; - + StringInfo res; + regex_t time_regex; + char *pattern; + int len_str = strlen(str); + char* modified_string = (char*) malloc(len_str + 1); + int j = 0; + char* temp_field; + + /* If sql_dialect is not an TSQL then return */ if (sql_dialect != SQL_DIALECT_TSQL) return false; @@ -2931,17 +2938,32 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) (errcode(ERRCODE_INVALID_DATETIME_FORMAT), \ errmsg("Conversion failed when converting date and/or time from character string."))); \ - dterr = ParseDateTime(str, workbuf, sizeof(workbuf), + /* Remove the spaces present before and after of ':', '/', '.', '-' */ + for (int i = 0; i < len_str; i++) + { + if (str[i] == ' ' && (str[i+1] == ' ' || str[i+1] == ':' || str[i+1] == '/' || str[i+1] == '.' || str[i+1] == '-')) + continue; + if (str[i] == ':' || str[i] == '/' || str[i] == '.' || str[i] == '-') + { + modified_string[j++] = str[i++]; + while (str[i] == ' ') + i++; + } + modified_string[j++] = str[i]; + } + modified_string[j] = '\0'; + + dterr = ParseDateTime(modified_string, workbuf, sizeof(workbuf), field, ftype, MAXDATEFIELDS, &nf); if (dterr == 0) { if (nf >= 3) { /* - * If the input is of format `DD MON YYY`, `DD YYYY MON`, `MON DD YYYY`, - * `MON YYYY DD`, `YYYY MON DD`, `YYYY DD MON`, then convert - * to format of `DD MON YYY`, `DD YYYY MON`, `YYYY MON DD`, `YYYY DD MON` - * and ftype changes to "DTK_DATE" + * If the input contains text month and is of format `DD MON YYY`, `DD YYYY MON`, + * `MON DD YYYY`, `MON YYYY DD`, `YYYY MON DD`, `YYYY DD MON`, then convert + * to format of `DD-MON-YYY`, `DD-YYYY-MON`, `YYYY-MON-DD`, `YYYY-DD-MON` + * and change ftype to "DTK_DATE" */ if (containsInTextMonthFormat(ftype, field)) { @@ -2954,9 +2976,10 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) field[0] = res->data; ftype[0] = DTK_DATE; nf = nf - 2; + /* - * Since the first 3 fields converted to 1, - * skip the attached fields. + * Since the first 3 fields converted to 1, skip the + * attached fields i.e., field[1]/[2], ftype[1]/[2] */ for(int i = 1; i < nf; i++) { @@ -2968,11 +2991,11 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) for (int i = 0; i < nf; i++) { - char *temp_field; int len; char* different_date_formats[] = {"/", ".", "-"}; temp_field = pstrdup(field[i]); len = strlen(temp_field); + switch (ftype[i]) { case DTK_NUMBER: @@ -2989,17 +3012,12 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) { case 1: case 2: - /* - * At this point the digit number of length 1,2 should be considered as - * time only if there is an [ap]m after the number or else - * should throw an error - */ - if (i == nf - 1 || ftype[i+1] != DTK_STRING) - TIME_IN_ERROR(); /* * For example if the input is "1 am" * will be converted to "1:00:00 am". */ + if (i == nf - 1 || ftype[i+1] != DTK_STRING) + TIME_IN_ERROR(); if (pg_strcasecmp(field[i+1], "am") == 0 || pg_strcasecmp(field[i+1], "pm") == 0) { res = makeStringInfo(); @@ -3013,8 +3031,6 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) case 4: /* - * If the numeric input is of length 4, then convert - * to year with default format of YYYY-01-01. * For example if input is "2000" will be converted * to "2000-01-01". */ @@ -3035,7 +3051,7 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) for (int k = 0; k < len; k++) { appendStringInfo(res, "%c", temp_field[k]); - if((len == 6 && ((k + 1) % 2 == 0 && k < 5)) || + if ((len == 6 && ((k + 1) % 2 == 0 && k < 5)) || (len == 8 && (k == 3 || k == 5))) appendStringInfo(res, "%c", '-'); } @@ -3050,31 +3066,85 @@ bool pltsql_time_in(const char* str, int32 typmod, TimeADT *result) case DTK_DATE: /* - * If the input is of format `Mon{/.-}yyyy{/.-}dd` or `Mon{/.-}dd{/.-}yyyy - * "DD MM YYYY", "DD YYYY MM", "MM YYYY DD", "MM DD YYYY", "YYYY DD MM", - * "YYYY MM DD", "DD{/.-}MM{/.-}YYYY", "DD{/.-}YYYY{/.-}DD" - * shouldn't be supported. - * Supported date formats are `Mon yyyy dd`, `Mon dd yyyy`, - * `mm{-/.}dd{-/.}yyyy`, `yyyy{-/.}mm{-/.}dd` + * If the input is of format 'T