diff --git a/src/common/backend/catalog/builtin_funcs.ini b/src/common/backend/catalog/builtin_funcs.ini index 8d614ddc9..a3e1942c7 100644 --- a/src/common/backend/catalog/builtin_funcs.ini +++ b/src/common/backend/catalog/builtin_funcs.ini @@ -12205,10 +12205,11 @@ AddFuncGroup( AddBuiltinFunc(_0(5260), _1("to_number"), _2(6), _3(false), _4(false), _5(numeric_to_default_without_defaultval), _6(1700), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(6, 25, 25, 16, 16, 25, 25), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("numeric_to_default_without_defaultval"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(NULL), _32(false), _33("convert text to numeric without default"), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) ), AddFuncGroup( - "to_timestamp", 3, + "to_timestamp", 4, AddBuiltinFunc(_0(1158), _1("to_timestamp"), _2(1), _3(true), _4(false), _5(float8_timestamptz), _6(1184), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('i'), _19(0), _20(1, 701), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("float8_timestamptz"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(NULL), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)), AddBuiltinFunc(_0(TOTIMESTAMPFUNCOID), _1("to_timestamp"), _2(2), _3(true), _4(false), _5(to_timestamp), _6(1114), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(2, 25, 25), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("to_timestamp"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(true), _32(false), _33("convert text to timestamp with time zone"), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)), - AddBuiltinFunc(_0(TOTIMESTAMPDEFAULTFUNCOID), _1("to_timestamp"), _2(1), _3(true), _4(false), _5(to_timestamp_default_format), _6(1114), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(1, 25), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("to_timestamp_default_format"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(true), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) + AddBuiltinFunc(_0(TOTIMESTAMPDEFAULTFUNCOID), _1("to_timestamp"), _2(1), _3(true), _4(false), _5(to_timestamp_default_format), _6(1114), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(1, 25), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("to_timestamp_default_format"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(true), _32(false), _33(NULL), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)), + AddBuiltinFunc(_0(5263), _1("to_timestamp"), _2(6), _3(false), _4(false), _5(to_timestamp_with_default_val), _6(1114), _7(PG_CATALOG_NAMESPACE), _8(BOOTSTRAP_SUPERUSERID), _9(INTERNALlanguageId), _10(1), _11(0), _12(0), _13(0), _14(false), _15(false), _16(false), _17(false), _18('s'), _19(0), _20(6, 25, 25, 16, 16, 25, 25), _21(NULL), _22(NULL), _23(NULL), _24(NULL), _25("to_timestamp_with_default_val"), _26(NULL), _27(NULL), _28(NULL), _29(0), _30(false), _31(true), _32(false), _33("convert text to timestamp with default and format"), _34('f'), _35(NULL), _36(0), _37(false), _38(NULL), _39(NULL), _40(0)) ), AddFuncGroup( "to_tsquery", 2, diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index 18a583be3..060797198 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -525,7 +525,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); %type defacl_privilege_target %type DefACLOption %type DefACLOptionList -%type opt_default_fmt_clause +%type opt_default_fmt_clause opt_default_nls_clause %type stmtblock stmtmulti OptTableElementList TableElementList OptInherit definition tsconf_definition @@ -28773,6 +28773,36 @@ func_application_special: func_name '(' ')' n->call_func = false; $$ = (Node *)n; } + | func_name '(' func_arg_list DEFAULT func_arg_expr ON CONVERSION_P ERROR_P ')' + { + if (u_sess->attr.attr_sql.sql_compatibility != A_FORMAT) { + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("The syntax or function is not supported. \"%s\"", $4))); + } + + FuncCall *n = makeNode(FuncCall); + n->funcname = $1; + + n->args = lappend($3, $5); + // is DEFAULT gramy + n->args = lappend(n->args, makeBoolAConst(TRUE, -1)); + // default expr is column ref + n->args = lappend(n->args, makeBoolAConst(IsA($5, ColumnRef), -1)); + // fmt constraints is NULL + n->args = lappend(n->args, makeNullAConst(-1)); + // nls param constraints is NULL + n->args = lappend(n->args, makeNullAConst(-1)); + + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = NULL; + n->location = @1; + n->call_func = false; + $$ = (Node *) n; + } | func_name '(' func_arg_list DEFAULT func_arg_expr ON CONVERSION_P ERROR_P opt_default_fmt_clause ')' { if (u_sess->attr.attr_sql.sql_compatibility != A_FORMAT) { @@ -28794,9 +28824,9 @@ func_application_special: func_name '(' ')' // default expr is column ref n->args = lappend(n->args, makeBoolAConst(IsA($5, ColumnRef), -1)); // There may be fmt constraints - n->args = lappend(n->args, $9); - // There may be nls param constraints - n->args = lappend(n->args, makeNullAConst(-1)); + n->args = lappend(n->args, $9); + // nls param constraints is NULL + n->args = lappend(n->args, makeNullAConst(-1)); n->agg_order = NIL; n->agg_star = FALSE; @@ -28807,6 +28837,12 @@ func_application_special: func_name '(' ')' n->call_func = false; $$ = (Node *) n; } + | func_name '(' func_arg_list DEFAULT func_arg_expr ON CONVERSION_P ERROR_P opt_default_fmt_clause opt_default_nls_clause ')' + { + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Syntax with nls condition is not supported."))); + } | func_name '(' VARIADIC func_arg_expr opt_sort_clause ')' { FuncCall *n = makeNode(FuncCall); @@ -28893,11 +28929,17 @@ func_application_special: func_name '(' ')' } ; + opt_default_fmt_clause: - ',' a_expr { $$ = $2; } - | /*EMPTY*/ { - $$ = makeNullAConst(-1); - } + ',' a_expr { + $$ = $2; + } + ; + +opt_default_nls_clause: + ',' a_expr { + $$ = $2; + } ; /* diff --git a/src/common/backend/utils/adt/formatting.cpp b/src/common/backend/utils/adt/formatting.cpp index 06bd03fea..74c11d644 100644 --- a/src/common/backend/utils/adt/formatting.cpp +++ b/src/common/backend/utils/adt/formatting.cpp @@ -7405,6 +7405,7 @@ void Init_NUM_cache(void) t_thrd.format_cxt.last_NUM_cache_entry = t_thrd.format_cxt.NUM_cache + 0; } +// to_timestamp(string) Datum to_timestamp_default_format(PG_FUNCTION_ARGS) { text* date_txt = PG_GETARG_TEXT_P(0); @@ -7424,6 +7425,67 @@ Datum to_timestamp_default_format(PG_FUNCTION_ARGS) PG_RETURN_TIMESTAMP(result); } +// to_timestamp(text DEFAULT RETURN_VALUE ON CONVERSION ERROR[, fmt[, nlsparam]]), _20(6, 25, 25, 16, 16, 25, 25) +Datum to_timestamp_with_default_val(PG_FUNCTION_ARGS) +{ + // args0 is text expr; args1 is default val; args2 is is DEFAULT gramy(bool); + // args3 is default expr is column ref(bool); args4 is fmt constraints; + // args5 is nls param constraints + text* date_txt = PG_GETARG_TEXT_P(0); + bool default_val_is_null = PG_ARGISNULL(1); + bool fmtIsNull = PG_ARGISNULL(4); + text* fmt; + if (fmtIsNull) { + fmt = cstring_to_text(u_sess->attr.attr_common.nls_timestamp_format_string); + } + else { + fmt = PG_GETARG_TEXT_P(4); + } + + bool resultNull = false; + Timestamp result; + int tz = 0; + + struct pg_tm tm; + fsec_t fsec; + + PG_TRY(); + { + do_to_timestamp(date_txt, fmt, &tm, &fsec); + + if (tm2timestamp(&tm, fsec, &tz, &result) != 0) { + ereport(ERROR, (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), errmsg("timestamp out of range"))); + } + + pfree_ext(fmt); + } + PG_CATCH(); + { + FlushErrorState(); + + if (default_val_is_null) { + pfree_ext(fmt); + resultNull = true; + } else { + text* defaultVal = PG_GETARG_TEXT_P(1); + + do_to_timestamp(defaultVal, fmt, &tm, &fsec); + pfree_ext(fmt); + + if (tm2timestamp(&tm, fsec, &tz, &result) != 0) { + ereport(ERROR, (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), errmsg("timestamp defaultVal out of range"))); + } + } + } + PG_END_TRY(); + + if (resultNull) { + PG_RETURN_NULL(); + } else { + PG_RETURN_TIMESTAMP(result); + } +} + /* * @Description: Given time pattern, time string and its constraint, * check and parse time string to time value. diff --git a/src/common/backend/utils/init/globals.cpp b/src/common/backend/utils/init/globals.cpp index 40e37a6ac..bad05f1c7 100644 --- a/src/common/backend/utils/init/globals.cpp +++ b/src/common/backend/utils/init/globals.cpp @@ -77,7 +77,7 @@ bool will_shutdown = false; * ********************************************/ -const uint32 GRAND_VERSION_NUM = 93007; +const uint32 GRAND_VERSION_NUM = 93008; /******************************************** * 2.VERSION NUM FOR EACH FEATURE diff --git a/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_008.sql b/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_008.sql new file mode 100644 index 000000000..24b2733c8 --- /dev/null +++ b/src/include/catalog/upgrade_sql/rollback_catalog_maindb/rollback-post_catalog_maindb_93_008.sql @@ -0,0 +1 @@ +DROP FUNCTION IF EXISTS pg_catalog.to_timestamp(text, text, bool, bool, text, text) CASCADE; \ No newline at end of file diff --git a/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_008.sql b/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_008.sql new file mode 100644 index 000000000..24b2733c8 --- /dev/null +++ b/src/include/catalog/upgrade_sql/rollback_catalog_otherdb/rollback-post_catalog_otherdb_93_008.sql @@ -0,0 +1 @@ +DROP FUNCTION IF EXISTS pg_catalog.to_timestamp(text, text, bool, bool, text, text) CASCADE; \ No newline at end of file diff --git a/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_008.sql b/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_008.sql new file mode 100644 index 000000000..7b60c5deb --- /dev/null +++ b/src/include/catalog/upgrade_sql/upgrade_catalog_maindb/upgrade-post_catalog_maindb_93_008.sql @@ -0,0 +1,8 @@ +DROP FUNCTION IF EXISTS pg_catalog.to_timestamp(text, text, bool, bool, text, text) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 5263; +CREATE FUNCTION pg_catalog.to_timestamp(text, text, bool, bool, text, text) +RETURNS INTERVAL +as 'to_timestamp_with_default_val' +LANGUAGE INTERNAL +stable; +COMMENT ON FUNCTION pg_catalog.to_timestamp(text, text, bool, bool, text, text) IS 'convert text to timestamp with default and format'; diff --git a/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_008.sql b/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_008.sql new file mode 100644 index 000000000..7b60c5deb --- /dev/null +++ b/src/include/catalog/upgrade_sql/upgrade_catalog_otherdb/upgrade-post_catalog_otherdb_93_008.sql @@ -0,0 +1,8 @@ +DROP FUNCTION IF EXISTS pg_catalog.to_timestamp(text, text, bool, bool, text, text) CASCADE; +SET LOCAL inplace_upgrade_next_system_object_oids = IUO_PROC, 5263; +CREATE FUNCTION pg_catalog.to_timestamp(text, text, bool, bool, text, text) +RETURNS INTERVAL +as 'to_timestamp_with_default_val' +LANGUAGE INTERNAL +stable; +COMMENT ON FUNCTION pg_catalog.to_timestamp(text, text, bool, bool, text, text) IS 'convert text to timestamp with default and format'; diff --git a/src/include/utils/formatting.h b/src/include/utils/formatting.h index a6a1f9d3a..15d75f54a 100644 --- a/src/include/utils/formatting.h +++ b/src/include/utils/formatting.h @@ -106,6 +106,7 @@ extern Datum float8_to_char(PG_FUNCTION_ARGS); #include "pgtime.h" #include "datatype/timestamp.h" extern Datum to_timestamp_default_format(PG_FUNCTION_ARGS); +extern Datum to_timestamp_with_default_val(PG_FUNCTION_ARGS); typedef struct TmToChar { struct pg_tm tm; /* classic 'tm' struct */ fsec_t fsec; /* fractional seconds */ diff --git a/src/test/regress/expected/to_timestamp_default.out b/src/test/regress/expected/to_timestamp_default.out new file mode 100644 index 000000000..6e962aba0 --- /dev/null +++ b/src/test/regress/expected/to_timestamp_default.out @@ -0,0 +1,1445 @@ +-- For function TO_TIMESTAMP +-- float8_timestamptz +SELECT TO_TIMESTAMP(' Infinity'::float); + to_timestamp +-------------- + infinity +(1 row) + +SELECT TO_TIMESTAMP('-Infinity'::float); + to_timestamp +-------------- + -infinity +(1 row) + +SELECT TO_TIMESTAMP('NaN'::float); +ERROR: timestamp cannot be NaN +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP(-999888762478); +ERROR: timestamp out of range: "-9.99889e+11" +CONTEXT: referenced column: to_timestamp +--------------------------------------------- +--------- 12-hour clock(DEFAULT FMT) -------- +--------------------------------------------- +SET nls_timestamp_format = 'YYYY-MM-DD HH:MI:SS.FF AM'; +SHOW nls_timestamp_format; + nls_timestamp_format +--------------------------- + YYYY-MM-DD HH:MI:SS.FF AM +(1 row) + +SELECT TO_TIMESTAMP('1998'); + to_timestamp +-------------------------- + Thu Jan 01 00:00:00 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28'); + to_timestamp +-------------------------- + Mon Dec 28 00:00:00 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01'); + to_timestamp +-------------------------- + Mon Dec 28 01:00:00 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02'); + to_timestamp +-------------------------- + Mon Dec 28 01:02:00 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02:03'); + to_timestamp +-------------------------- + Mon Dec 28 01:02:03 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12'); + to_timestamp +----------------------------- + Mon Dec 28 01:02:03.12 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12 AM'); + to_timestamp +----------------------------- + Mon Dec 28 01:02:03.12 1998 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 11:12:13 PM'); +ERROR: invalid value "PM" for "FF" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01'); + to_timestamp +-------------------------- + Mon Jan 01 00:00:00 0001 +(1 row) + +SELECT TO_TIMESTAMP('01', 'yyyy-MM-dd'); + to_timestamp +-------------------------- + Mon Jan 01 00:00:00 0001 +(1 row) + +-- TO_TIMESTAMP(text) +SHOW nls_timestamp_format; + nls_timestamp_format +--------------------------- + YYYY-MM-DD HH:MI:SS.FF AM +(1 row) + +SELECT TO_TIMESTAMP('01'); + to_timestamp +-------------------------- + Mon Jan 01 00:00:00 0001 +(1 row) + +SELECT TO_TIMESTAMP('01-Sep'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12 PM'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13 PM'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +-- TO_TIMESTAMP(text, fmt) +SET DateStyle TO 'ISO, MDY'; +SELECT TO_TIMESTAMP('32-1-1','DD-MM-YYYY'); +ERROR: invalid data for "day of month = 32" ,value must be between 1 and 31 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('31-1-1','DD-MM-YYYY'); + to_timestamp +--------------------- + 0001-01-31 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1-1-1','DD-MM-YYYY'); + to_timestamp +--------------------- + 0001-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('0-1-1','DD-MM-YYYY'); +ERROR: invalid data for "day of month = 0" ,value must be between 1 and 31 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1-0-1','DD-MM-YYYY'); +ERROR: invalid data for "month = 0" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1-1-1','DD-MM-YYYY'); + to_timestamp +--------------------- + 0001-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1-12-1','DD-MM-YYYY'); + to_timestamp +--------------------- + 0001-12-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1-13-1','DD-MM-YYYY'); +ERROR: invalid data for "month = 13" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('28-2-1','DD-MM-YYYY'); + to_timestamp +--------------------- + 0001-02-28 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('29-2-1','DD-MM-YYYY'); +ERROR: invalid data for "day of month = 29" ,value must be be fit for current month +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('29-2-4','DD-MM-YYYY'); + to_timestamp +--------------------- + 0004-02-29 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('0-1','DDD-YYYY'); +ERROR: invalid data for "days of year = 0" ,value must be between 1 and 366 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('367-1','DDD-YYYY'); +ERROR: invalid data for "days of year = 367" ,value must be between 1 and 366 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('366-1','DDD-YYYY'); +ERROR: invalid data for "days of year = 366" ,value must be be fit for current year +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('366-4','DDD-YYYY'); + to_timestamp +--------------------- + 0004-12-31 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('0','HH12'); +ERROR: invalid data for "hour = 0" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1','HH12'); + to_timestamp +------------------------ + 0001-01-01 01:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('12','HH12'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('13','HH12'); +ERROR: invalid data for "hour = 13" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0','MI'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('59','MI'); + to_timestamp +------------------------ + 0001-01-01 00:59:00 BC +(1 row) + +SELECT TO_TIMESTAMP('60','MI'); + to_timestamp +------------------------ + 0001-01-01 01:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('0','SS'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('59','SS'); + to_timestamp +------------------------ + 0001-01-01 00:00:59 BC +(1 row) + +SELECT TO_TIMESTAMP('60','SS'); + to_timestamp +------------------------ + 0001-01-01 00:01:00 BC +(1 row) + +SELECT TO_TIMESTAMP('60','DDD-PS'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('366-4','YYYY-P'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('366-4','YYYY-DD-12'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713','YYYY'); +ERROR: invalid data for "year = -4713" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712','YYYY'); +ERROR: invalid data for "year = -4712" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1','YYYY'); +ERROR: invalid data for "year = -1" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('0','YYYY'); +ERROR: invalid data for "year = 0" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('1','YYYY'); + to_timestamp +--------------------- + 0001-01-01 00:00:00 +(1 row) + +select TO_TIMESTAMP('9999','YYYY'); + to_timestamp +--------------------- + 9999-01-01 00:00:00 +(1 row) + +select TO_TIMESTAMP('10000','YYYY'); +ERROR: invalid data for "year = 10000" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 pm', 'yyyymmdd hh:MI pm'); + to_timestamp +--------------------- + 2012-09-30 21:30:00 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 p.m.', 'yyyymmdd hh:MI p.m.'); + to_timestamp +--------------------- + 2012-09-30 21:30:00 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 111', 'yyyymmdd hh:MI MS'); + to_timestamp +------------------------- + 2012-09-30 09:30:00.111 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 111', 'yyyymmdd hh:MI US'); + to_timestamp +------------------------- + 2012-09-30 09:30:00.111 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 11111', 'yyyymmdd hh:MI SSSSS'); +ERROR: minutes of hour conflicts with seconds in day +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 11111 TZ', 'yyyymmdd hh:MI SSSSS TZ'); +ERROR: "TZ"/"tz" format patterns are not supported in to_date +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 111 B.C.', 'yyyymmdd hh:MI US B.C.'); + to_timestamp +---------------------------- + 2012-09-30 09:30:00.111 BC +(1 row) + +select TO_TIMESTAMP('20120930 09:30 111 BC', 'yyyymmdd hh:MI US BC'); + to_timestamp +---------------------------- + 2012-09-30 09:30:00.111 BC +(1 row) + +select TO_TIMESTAMP('20120930 09:30 111 fri', 'yyyymmdd hh:MI US dy'); + to_timestamp +------------------------- + 2012-09-30 09:30:00.111 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 111 fri 3', 'yyyymmdd hh:MI US dy Q'); + to_timestamp +------------------------- + 2012-09-30 09:30:00.111 +(1 row) + +select TO_TIMESTAMP('2012I30 09:30 111 fri 3', 'yyyyRMdd hh:MI US dy Q'); + to_timestamp +------------------------- + 2012-01-30 09:30:00.111 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 5 1234', 'yyyymmdd hh:MI W J'); +ERROR: year conflicts with Julian date +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 pm', 'yyyymmdd hh:MI pm FF'); + to_timestamp +--------------------- + 2012-09-30 21:30:00 +(1 row) + +select TO_TIMESTAMP('20120930 09:30 5555', 'yyyymmdd hh:MI RRRR'); +ERROR: conflicting values for "RRRR" field in formatting string +DETAIL: This value contradicts a previous setting for the same field type. +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 55', 'yyyymmdd hh:MI RR'); +ERROR: conflicting values for "RR" field in formatting string +DETAIL: This value contradicts a previous setting for the same field type. +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('20120930 09:30 55', 'yyyymmdd hh:MI FF'); + to_timestamp +------------------------ + 2012-09-30 09:30:00.55 +(1 row) + +SELECT TO_TIMESTAMP('0000-09-01','YYYYY-MM-DD'); +ERROR: conflicting values for "Y" field in formatting string +DETAIL: This value contradicts a previous setting for the same field type. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0000-09-01','SYYYYY-MM-DD'); +ERROR: invalid value "0000-" for "SYYYY" +DETAIL: Field requires 5 characters, but only 4 could be parsed. +HINT: If your source string is not fixed-width, try using the "FM" modifier. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0000-09-01','SYYYY-Y-MM-DD'); +ERROR: conflicting values for "Y" field in formatting string +DETAIL: This value contradicts a previous setting for the same field type. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('25361','SSSSS'); + to_timestamp +------------------------ + 0001-01-01 07:02:41 BC +(1 row) + +SELECT TO_TIMESTAMP('25361-2','SSSSS-HH12'); +ERROR: hour conflicts with seconds in day +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('25361-07','SSSSS-HH12'); + to_timestamp +------------------------ + 0001-01-01 07:02:41 BC +(1 row) + +SELECT TO_TIMESTAMP('25361-2','SSSSS-MI'); + to_timestamp +------------------------ + 0001-01-01 07:02:41 BC +(1 row) + +SELECT TO_TIMESTAMP('25361-10','SSSSS-MI'); +ERROR: minutes of hour conflicts with seconds in day +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('25361-2','SSSSS-SS'); +ERROR: seconds of minute conflicts with seconds in day +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('25361-41','SSSSS-SS'); + to_timestamp +------------------------ + 0001-01-01 07:02:41 BC +(1 row) + +SELECT TO_TIMESTAMP('2650000','J'); + to_timestamp +--------------------- + 2543-05-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2650000-2542','J-YYYY'); +ERROR: year conflicts with Julian date +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2650000-2543','J-YYYY'); + to_timestamp +--------------------- + 2543-05-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2650000-4','J-MM'); +ERROR: month conflicts with Julian date +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2650000-5','J-MM'); + to_timestamp +--------------------- + 2543-05-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2650000-8','J-DD'); +ERROR: day conflicts with Julian date +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2650000-9','J-DD'); + to_timestamp +--------------------- + 2543-05-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-245','YYYY-DDD'); + to_timestamp +--------------------- + 2012-09-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-245-8','YYYY-DDD-MM'); +ERROR: month conflicts with days of year +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-245-9','YYYY-DDD-MM'); + to_timestamp +--------------------- + 2012-09-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-245-1','YYYY-DDD-DD'); + to_timestamp +--------------------- + 2012-09-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-245-2','YYYY-DDD-DD'); +ERROR: days of month conflicts with days of year +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('2012-11-15','YYYY-MM-DD'); + to_timestamp +--------------------- + 2012-11-15 00:00:00 +(1 row) + +--MS +SELECT TO_TIMESTAMP('-1','MS'); +ERROR: invalid data for "millisecond = -10" ,value must be between 0 and 999 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0','MS'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('256','MS'); + to_timestamp +---------------------------- + 0001-01-01 00:00:00.256 BC +(1 row) + +SELECT TO_TIMESTAMP('999','MS'); + to_timestamp +---------------------------- + 0001-01-01 00:00:00.999 BC +(1 row) + +SELECT TO_TIMESTAMP('1000','MS'); +ERROR: invalid data for "millisecond = 1000" ,value must be between 0 and 999 +CONTEXT: referenced column: to_timestamp +--WW +SELECT TO_TIMESTAMP('0','WW'); +ERROR: invalid data for "week number of year = 0" ,value must be between 1 and 53 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1','WW'); +ERROR: cannot calculate day of year without year information +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('10','WW'); +ERROR: cannot calculate day of year without year information +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('53','WW'); +ERROR: cannot calculate day of year without year information +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('54','WW'); +ERROR: invalid data for "week number of year = 54" ,value must be between 1 and 53 +CONTEXT: referenced column: to_timestamp +--D +SELECT TO_TIMESTAMP('0','D'); +ERROR: invalid data for "day = 0" ,value must be between 1 and 7 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1','D'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('4','D'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('7','D'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('8','D'); +ERROR: invalid data for "day = 8" ,value must be between 1 and 7 +CONTEXT: referenced column: to_timestamp +--WW & D YYYY +SELECT TO_TIMESTAMP('2012-50-0','YYYY-WW-D'); +ERROR: invalid data for "day = 0" ,value must be between 1 and 7 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-50-1','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-12-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-50-4','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-12-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-50-7','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-12-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-50-8','YYYY-WW-D'); +ERROR: invalid data for "day = 8" ,value must be between 1 and 7 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-0-4','YYYY-WW-D'); +ERROR: invalid data for "week number of year = 0" ,value must be between 1 and 53 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-1-4','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-50-4','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-12-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-53-4','YYYY-WW-D'); + to_timestamp +--------------------- + 2012-12-30 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2012-54-4','YYYY-WW-D'); +ERROR: invalid data for "week number of year = 54" ,value must be between 1 and 53 +CONTEXT: referenced column: to_timestamp +--US +SELECT TO_TIMESTAMP('-1','US'); +ERROR: invalid data for "microsecond = -10000" ,value must be between 1 and 999999 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0','US'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('99999','US'); + to_timestamp +------------------------------ + 0001-01-01 00:00:00.99999 BC +(1 row) + +SELECT TO_TIMESTAMP('999999','US'); + to_timestamp +------------------------------- + 0001-01-01 00:00:00.999999 BC +(1 row) + +SELECT TO_TIMESTAMP('1000000','US'); +ERROR: input length of format 'US'/'us'/'FF'/'ff' must between 0 and 6 +CONTEXT: referenced column: to_timestamp +--W +SELECT TO_TIMESTAMP('-1','W'); +ERROR: invalid data for "week of month = -1" ,value must be between 1 and 5 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0','W'); +ERROR: invalid data for "week of month = 0" ,value must be between 1 and 5 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1','W'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('5','W'); + to_timestamp +------------------------ + 0001-01-29 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('6','W'); +ERROR: invalid data for "week of month = 6" ,value must be between 1 and 5 +CONTEXT: referenced column: to_timestamp +--DCH_check +select TO_TIMESTAMP('13' ,'HH'); +ERROR: invalid data for "hour = 13" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('25','HH24'); +ERROR: invalid data for "hour = 25" ,value must be between 0 and 24 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('62','MI'); +ERROR: invalid data for "minute = 62" ,value must be between 0 and 60 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('62','SS'); +ERROR: invalid data for "second = 62" ,value must be between 0 and 60 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('86400','SSSSS'); + to_timestamp +------------------------ + 0001-01-02 00:00:00 BC +(1 row) + +select TO_TIMESTAMP('8','D'); +ERROR: invalid data for "day = 8" ,value must be between 1 and 7 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('32','DD'); +ERROR: invalid data for "day of month = 32" ,value must be between 1 and 31 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('367','DDD'); +ERROR: invalid data for "days of year = 367" ,value must be between 1 and 366 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('36','MM'); +ERROR: invalid data for "month = 36" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('1000','MS'); +ERROR: invalid data for "millisecond = 1000" ,value must be between 0 and 999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('54','WW'); +ERROR: invalid data for "week number of year = 54" ,value must be between 1 and 53 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('7','W'); +ERROR: invalid data for "week of month = 7" ,value must be between 1 and 5 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('5373485','J'); +ERROR: invalid data for "julian day = 5373485" ,value must be between 1 and 5373484 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1','US'); +ERROR: invalid data for "microsecond = -10000" ,value must be between 1 and 999999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('10000','SYYYY'); +ERROR: invalid data for "year = 10000" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('10000','RR'); +ERROR: invalid data for "year(RR/RRRR) = 10000" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +SHOW nls_timestamp_format; + nls_timestamp_format +--------------------------- + YYYY-MM-DD HH:MI:SS.FF AM +(1 row) + +SELECT TO_TIMESTAMP('0097/Feb/16 --> 08:14:30', 'YYYY/Mon/DD --> HH:MI:SS'); + to_timestamp +--------------------- + 0097-02-16 08:14:30 +(1 row) + +SELECT TO_TIMESTAMP('97/2/16 8:14:30', 'FMYYYY/FMMM/FMDD FMHH:FMMI:FMSS'); + to_timestamp +--------------------- + 0097-02-16 08:14:30 +(1 row) + +SELECT TO_TIMESTAMP('1985 January 12', 'YYYY FMMonth DD'); + to_timestamp +--------------------- + 1985-01-12 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('My birthday-> Year: 1976, Month: May, Day: 16', + '"My birthday-> Year" YYYY, "Month:" FMMonth, "Day:" DD'); + to_timestamp +--------------------- + 1976-05-16 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1,582nd VIII 21', 'Y,YYYth FMRM DD'); + to_timestamp +--------------------- + 1582-08-21 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('15 "text between quote marks" 98 54 45', + E'HH24 "\\text between quote marks\\"" YY MI SS'); + to_timestamp +--------------------- + 1998-01-01 15:54:45 +(1 row) + +SELECT TO_TIMESTAMP('05121445482000', 'MMDDHH24MISSYYYY'); + to_timestamp +--------------------- + 2000-05-12 14:45:48 +(1 row) + +SELECT TO_TIMESTAMP('2000January09Sunday', 'YYYYFMMonthDDFMDay'); + to_timestamp +--------------------- + 2000-01-09 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('97/Feb/16', 'YYMonDD'); +ERROR: invalid value "/Fe" for "Mon" +DETAIL: The given value did not match any of the allowed values for this field. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('19971116', 'YYYYMMDD'); + to_timestamp +--------------------- + 1997-11-16 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('20000-1116', 'YYYY-MMDD'); +ERROR: invalid data for "year = 20000" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('9-1116', 'Y-MMDD'); + to_timestamp +--------------------- + 2009-11-16 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('95-1116', 'YY-MMDD'); + to_timestamp +--------------------- + 1995-11-16 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('995-1116', 'YYY-MMDD'); + to_timestamp +--------------------- + 1995-11-16 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2005426', 'YYYYWWD'); + to_timestamp +--------------------- + 2005-10-15 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2005300', 'YYYYDDD'); + to_timestamp +--------------------- + 2005-10-27 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2005527', 'IYYYIWID'); + to_timestamp +--------------------- + 2006-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('005527', 'IYYIWID'); + to_timestamp +--------------------- + 2006-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('05527', 'IYIWID'); + to_timestamp +--------------------- + 2006-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('5527', 'IIWID'); + to_timestamp +--------------------- + 2006-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2005364', 'IYYYIDDD'); + to_timestamp +--------------------- + 2006-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('20050302', 'YYYYMMDD'); + to_timestamp +--------------------- + 2005-03-02 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('2005 03 02', 'YYYYMMDD'); + to_timestamp +--------------------- + 2005-03-02 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP(' 2005 03 02', 'YYYYMMDD'); + to_timestamp +--------------------- + 2005-03-02 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP(' 20050302', 'YYYYMMDD'); + to_timestamp +--------------------- + 2005-03-02 00:00:00 +(1 row) + +SHOW nls_timestamp_format; + nls_timestamp_format +--------------------------- + YYYY-MM-DD HH:MI:SS.FF AM +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015'); -- error: ERROR: invalid data for "hour = 13" ,value must be between 1 and 12 +ERROR: invalid data for "hour = 13" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SHOW nls_timestamp_format; + nls_timestamp_format +--------------------------- + YYYY-MM-DD HH:MI:SS.FF AM +(1 row) + +-- with default +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT NULL ON CONVERSION ERROR); + to_timestamp +-------------- + +(1 row) + +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT '1,582nd VIII 21' ON CONVERSION ERROR); +ERROR: invalid value "d " for "DD" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR); + to_timestamp +-------------- + +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR); + to_timestamp +--------------------- + 2012-11-15 00:00:00 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR); + to_timestamp +-------------- + +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR); + to_timestamp +--------------------- + 2012-11-15 00:00:00 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT 'abc' ON CONVERSION ERROR); +ERROR: invalid value "abc" for "YYYY" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT 3.14 ON CONVERSION ERROR); -- error: ERROR: invalid data for "month = 14" ,value must be between 1 and 12 +ERROR: invalid data for "month = 14" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT '2010-01-01 01:00:00' ON CONVERSION ERROR); + to_timestamp +--------------------- + 2010-01-01 01:00:00 +(1 row) + +--------------------------------------------- +--------- 24-hour clock(DEFAULT FMT) -------- +--------------------------------------------- +SET nls_timestamp_format = 'YYYY-MM-DD HH:MI:SS'; +SHOW nls_timestamp_format; + nls_timestamp_format +---------------------- + YYYY-MM-DD HH:MI:SS +(1 row) + +SELECT TO_TIMESTAMP('1998'); + to_timestamp +--------------------- + 1998-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28'); + to_timestamp +--------------------- + 1998-12-28 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01'); + to_timestamp +--------------------- + 1998-12-28 01:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02'); + to_timestamp +--------------------- + 1998-12-28 01:02:00 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02:03'); + to_timestamp +--------------------- + 1998-12-28 01:02:03 +(1 row) + +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12'); +ERROR: invalid data for match in date string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12 AM'); +ERROR: invalid data for match in date string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1998-12-28 11:12:13 PM'); +ERROR: invalid data for match in date string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01'); + to_timestamp +--------------------- + 0001-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('01'); + to_timestamp +--------------------- + 0001-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('01-Sep'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12 PM'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13 PM'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 16:12:13'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 12:55:66'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 24:12:13'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 25:55:66'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 60:12:13'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('01-Sep-1998 12:60:00'); +ERROR: invalid value "Se" for "MM" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +--------------------------------------------- +--------- DEFINE FMT -------- +--------------------------------------------- +-- SET DateStyle TO 'ISO, MDY'; +select TO_TIMESTAMP('23 01 01','hh24 mi ss'); + to_timestamp +------------------------ + 0001-01-01 23:01:01 BC +(1 row) + +select TO_TIMESTAMP('20150101 232323','yyyymmdd hh24miss'); + to_timestamp +--------------------- + 2015-01-01 23:23:23 +(1 row) + +select TO_TIMESTAMP('20150101 232323','yyyymmdd hh24miss'); + to_timestamp +--------------------- + 2015-01-01 23:23:23 +(1 row) + +SELECT TO_TIMESTAMP('0','HH24'); + to_timestamp +------------------------ + 0001-01-01 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('23','HH24'); + to_timestamp +------------------------ + 0001-01-01 23:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('24','HH24'); + to_timestamp +------------------------ + 0001-01-02 00:00:00 BC +(1 row) + +SELECT TO_TIMESTAMP('24','H24'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('10','H24'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('10','H24'); +ERROR: invalid data for match in format string +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('1,582nd VIII 21', 'Y,YYYth FMRM DD'); + to_timestamp +--------------------- + 1582-08-21 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('-2012-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +ERROR: invalid data for "year = -2012" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('-1-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +ERROR: invalid data for "year = -1" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('0-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +ERROR: invalid data for "year = 0" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('9999-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); + to_timestamp +------------------------ + 9999-02-03 21:15:36.18 +(1 row) + +SELECT TO_TIMESTAMP('10000-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +ERROR: invalid data for "year = 10000" ,value must be between 1 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = -4713" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); + to_timestamp +------------------------------- + 4712-03-04 13:02:03.234015 BC +(1 row) + +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = 0" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = 10000" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = -4713" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); + to_timestamp +------------------------------- + 4712-03-04 13:02:03.234015 BC +(1 row) + +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = 0" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year = 10000" ,value must be between -4712 and 9999, and not be 0 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4713" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4712" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +ERROR: RR/RRRR should be between 0 - 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2000-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2001-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = 10000" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4713" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4712" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +ERROR: RR/RRRR should be between 0 - 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2000-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2001-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = 10000" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4713" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4712" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +ERROR: RR/RRRR should be between 0 - 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2000-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2001-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = 10000" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4713" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = -4712" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +ERROR: RR/RRRR should be between 0 - 9999 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2000-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 2001-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "year(RR/RRRR) = 10000" ,value must be between 0 and 9999 +CONTEXT: referenced column: to_timestamp +-- Mixture of date conventions (ISO week and Gregorian): +SELECT TO_TIMESTAMP('2005527', 'YYYYIWID'); -- error: Do not mix Gregorian and ISO week date conventions in a formatting template. +ERROR: invalid combination of date conventions +HINT: Do not mix Gregorian and ISO week date conventions in a formatting template. +CONTEXT: referenced column: to_timestamp +-- Insufficient characters in the source string: +SELECT TO_TIMESTAMP('19971', 'YYYYMMDD'); -- error: Field requires 2 characters, but only 1 remain. +ERROR: source string too short for "MM" formatting field +DETAIL: Field requires 2 characters, but only 1 remain. +HINT: If your source string is not fixed-width, try using the "FM" modifier. +CONTEXT: referenced column: to_timestamp +-- Insufficient digit characters for a single node: +SELECT TO_TIMESTAMP('19971)24', 'YYYYMMDD'); -- error; invalid value "1)" for "MM" +ERROR: invalid value "1)" for "MM" +DETAIL: Field requires 2 characters, but only 1 could be parsed. +HINT: If your source string is not fixed-width, try using the "FM" modifier. +CONTEXT: referenced column: to_timestamp +-- Value clobbering: +SELECT TO_TIMESTAMP('1997-11-Jan-16', 'YYYY-MM-Mon-DD'); -- error; conflicting values for "Mon" field in formatting string +ERROR: conflicting values for "Mon" field in formatting string +DETAIL: This value contradicts a previous setting for the same field type. +CONTEXT: referenced column: to_timestamp +-- Non-numeric input: +SELECT TO_TIMESTAMP('199711xy', 'YYYYMMDD'); -- error: invalid value "xy" for "DD" +ERROR: invalid value "xy" for "DD" +DETAIL: Value must be an integer. +CONTEXT: referenced column: to_timestamp +-- Input that doesn't fit in an int: +SELECT TO_TIMESTAMP('10000000000', 'FMYYYY'); -- error: value for "YYYY" in source string is out of range. +ERROR: value for "YYYY" in source string is out of range +DETAIL: Value must be in the range -2147483648 to 2147483647. +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2010-01-01 00:00:00','yyyy-mm-dd hh24:mi:ss'); + to_timestamp +--------------------- + 2010-01-01 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT '1,582nd VIII 21' ON CONVERSION ERROR, 'Y,YYYth FMRM DD'); + to_timestamp +--------------------- + 1582-08-21 00:00:00 +(1 row) + +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT 'abcdefg' ON CONVERSION ERROR, 'Y,YYYth FMRM DD'); +ERROR: invalid input string for "Y,YYY" +CONTEXT: referenced column: to_timestamp +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT 3.14 ON CONVERSION ERROR,'YYYY-DDD-DD'); + to_timestamp +--------------------- + 0003-01-14 00:00:00 +(1 row) + +select TO_TIMESTAMP('2012-11-15' DEFAULT NULL ON CONVERSION ERROR,'YYYY-MM-DD'); + to_timestamp +--------------------- + 2012-11-15 00:00:00 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +---------------------------- + 9999-03-04 13:02:03.234015 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +--------------------- + 2012-11-15 00:00:00 +(1 row) + +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT 3.14 ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); +ERROR: invalid data for "month = 14" ,value must be between 1 and 12 +CONTEXT: referenced column: to_timestamp +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); + to_timestamp +-------------- + +(1 row) + +-- USE TO_TIMESTAMP CHECKDAYS +SELECT (TO_TIMESTAMP('12:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')) * 24 *3600; + ?column? +------------- + @ 3600 days +(1 row) + +SELECT (TO_TIMESTAMP('18:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')) + (TO_TIMESTAMP('15:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')); + ?column? +------------ + @ 11 hours +(1 row) + +SELECT (TO_TIMESTAMP('23:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('00:34:04', 'hh24:mi:ss.sssss')) + (TO_TIMESTAMP('22:38:13', 'hh24:mi:ss') - TO_TIMESTAMP('02:45:53', 'hh24:mi:ss.sssss')); + ?column? +---------------------------------- + @ 1 day 19 hours 17 mins 20 secs +(1 row) + +--DAY > 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-5 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 02:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +---------------------------------- + @ 2 days 4 hours 32 mins 40 secs +(1 row) + +SELECT ((TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-5 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-2 02:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss'))) * 2; + ?column? +-------------------------- + @ 9 hours 5 mins 20 secs +(1 row) + +--DAY < 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 20:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +-------------------------------------- + @ 3 days 2 hours 27 mins 20 secs ago +(1 row) + +SELECT ((TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-7 20:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss'))) * 2; + ?column? +------------------------------- + @ 4 hours 54 mins 40 secs ago +(1 row) + +--DAY > 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +----------------------------------- + @ 9 days 21 hours 51 mins 50 secs +(1 row) + +--DAY = 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 00:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 23:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +---------------------------------- + @ 1 day 21 hours 58 mins 10 secs +(1 row) + +--DAY < 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 23:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-3 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +------------------------------------- + @ 6 days 22 hours 1 min 50 secs ago +(1 row) + +--DAY = 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 23:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +------------------------------------ + @ 1 day 22 hours 1 min 50 secs ago +(1 row) + +--DAY > 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +---------- + @ 7 days +(1 row) + +--DAY < 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-3 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +-------------- + @ 5 days ago +(1 row) + +--DAY = 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); + ?column? +---------- + @ 0 +(1 row) + diff --git a/src/test/regress/parallel_schedule0 b/src/test/regress/parallel_schedule0 index a8d2eb8ae..1b9de1256 100644 --- a/src/test/regress/parallel_schedule0 +++ b/src/test/regress/parallel_schedule0 @@ -1139,4 +1139,6 @@ test: ts_gb18030_utf8 test: backup_tool_audit # to_number func -test: to_number_default \ No newline at end of file +test: to_number_default +# to_timestamp func +test: to_timestamp_default \ No newline at end of file diff --git a/src/test/regress/parallel_schedule0C b/src/test/regress/parallel_schedule0C index 4672def87..ce05194c8 100644 --- a/src/test/regress/parallel_schedule0C +++ b/src/test/regress/parallel_schedule0C @@ -195,5 +195,6 @@ test: enable_expr_fusion_flatten # to_number func test: to_number_default - +# to_timestamp func +test: to_timestamp_default diff --git a/src/test/regress/sql/to_timestamp_default.sql b/src/test/regress/sql/to_timestamp_default.sql new file mode 100644 index 000000000..c7ad1c8e6 --- /dev/null +++ b/src/test/regress/sql/to_timestamp_default.sql @@ -0,0 +1,381 @@ +-- For function TO_TIMESTAMP + +-- float8_timestamptz +SELECT TO_TIMESTAMP(' Infinity'::float); +SELECT TO_TIMESTAMP('-Infinity'::float); +SELECT TO_TIMESTAMP('NaN'::float); +SELECT TO_TIMESTAMP(-999888762478); + +--------------------------------------------- +--------- 12-hour clock(DEFAULT FMT) -------- +--------------------------------------------- +SET nls_timestamp_format = 'YYYY-MM-DD HH:MI:SS.FF AM'; +SHOW nls_timestamp_format; + +SELECT TO_TIMESTAMP('1998'); +SELECT TO_TIMESTAMP('1998-12-28'); +SELECT TO_TIMESTAMP('1998-12-28 01'); +SELECT TO_TIMESTAMP('1998-12-28 01:02'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12 AM'); +SELECT TO_TIMESTAMP('1998-12-28 11:12:13 PM'); +SELECT TO_TIMESTAMP('01'); +SELECT TO_TIMESTAMP('01', 'yyyy-MM-dd'); + +-- TO_TIMESTAMP(text) +SHOW nls_timestamp_format; +SELECT TO_TIMESTAMP('01'); +SELECT TO_TIMESTAMP('01-Sep'); +SELECT TO_TIMESTAMP('01-Sep-1998'); +SELECT TO_TIMESTAMP('01-Sep-1998 11'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12 PM'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13 PM'); + +-- TO_TIMESTAMP(text, fmt) +SET DateStyle TO 'ISO, MDY'; + +SELECT TO_TIMESTAMP('32-1-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('31-1-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('1-1-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('0-1-1','DD-MM-YYYY'); + +SELECT TO_TIMESTAMP('1-0-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('1-1-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('1-12-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('1-13-1','DD-MM-YYYY'); + +SELECT TO_TIMESTAMP('28-2-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('29-2-1','DD-MM-YYYY'); +SELECT TO_TIMESTAMP('29-2-4','DD-MM-YYYY'); + +SELECT TO_TIMESTAMP('0-1','DDD-YYYY'); +SELECT TO_TIMESTAMP('367-1','DDD-YYYY'); +SELECT TO_TIMESTAMP('366-1','DDD-YYYY'); +SELECT TO_TIMESTAMP('366-4','DDD-YYYY'); + +SELECT TO_TIMESTAMP('0','HH12'); +SELECT TO_TIMESTAMP('1','HH12'); +SELECT TO_TIMESTAMP('12','HH12'); +SELECT TO_TIMESTAMP('13','HH12'); + +SELECT TO_TIMESTAMP('0','MI'); +SELECT TO_TIMESTAMP('59','MI'); +SELECT TO_TIMESTAMP('60','MI'); + +SELECT TO_TIMESTAMP('0','SS'); +SELECT TO_TIMESTAMP('59','SS'); +SELECT TO_TIMESTAMP('60','SS'); + +SELECT TO_TIMESTAMP('60','DDD-PS'); +SELECT TO_TIMESTAMP('366-4','YYYY-P'); +SELECT TO_TIMESTAMP('366-4','YYYY-DD-12'); + +select TO_TIMESTAMP('-4713','YYYY'); +select TO_TIMESTAMP('-4712','YYYY'); +select TO_TIMESTAMP('-1','YYYY'); +select TO_TIMESTAMP('0','YYYY'); +select TO_TIMESTAMP('1','YYYY'); +select TO_TIMESTAMP('9999','YYYY'); +select TO_TIMESTAMP('10000','YYYY'); + +select TO_TIMESTAMP('20120930 09:30 pm', 'yyyymmdd hh:MI pm'); +select TO_TIMESTAMP('20120930 09:30 p.m.', 'yyyymmdd hh:MI p.m.'); +select TO_TIMESTAMP('20120930 09:30 111', 'yyyymmdd hh:MI MS'); +select TO_TIMESTAMP('20120930 09:30 111', 'yyyymmdd hh:MI US'); +select TO_TIMESTAMP('20120930 09:30 11111', 'yyyymmdd hh:MI SSSSS'); +select TO_TIMESTAMP('20120930 09:30 11111 TZ', 'yyyymmdd hh:MI SSSSS TZ'); + +select TO_TIMESTAMP('20120930 09:30 111 B.C.', 'yyyymmdd hh:MI US B.C.'); +select TO_TIMESTAMP('20120930 09:30 111 BC', 'yyyymmdd hh:MI US BC'); +select TO_TIMESTAMP('20120930 09:30 111 fri', 'yyyymmdd hh:MI US dy'); +select TO_TIMESTAMP('20120930 09:30 111 fri 3', 'yyyymmdd hh:MI US dy Q'); + +select TO_TIMESTAMP('2012I30 09:30 111 fri 3', 'yyyyRMdd hh:MI US dy Q'); +select TO_TIMESTAMP('20120930 09:30 5 1234', 'yyyymmdd hh:MI W J'); +select TO_TIMESTAMP('20120930 09:30 pm', 'yyyymmdd hh:MI pm FF'); + +select TO_TIMESTAMP('20120930 09:30 5555', 'yyyymmdd hh:MI RRRR'); +select TO_TIMESTAMP('20120930 09:30 55', 'yyyymmdd hh:MI RR'); +select TO_TIMESTAMP('20120930 09:30 55', 'yyyymmdd hh:MI FF'); + +SELECT TO_TIMESTAMP('0000-09-01','YYYYY-MM-DD'); +SELECT TO_TIMESTAMP('0000-09-01','SYYYYY-MM-DD'); +SELECT TO_TIMESTAMP('0000-09-01','SYYYY-Y-MM-DD'); + +SELECT TO_TIMESTAMP('25361','SSSSS'); +SELECT TO_TIMESTAMP('25361-2','SSSSS-HH12'); +SELECT TO_TIMESTAMP('25361-07','SSSSS-HH12'); +SELECT TO_TIMESTAMP('25361-2','SSSSS-MI'); +SELECT TO_TIMESTAMP('25361-10','SSSSS-MI'); +SELECT TO_TIMESTAMP('25361-2','SSSSS-SS'); +SELECT TO_TIMESTAMP('25361-41','SSSSS-SS'); + +SELECT TO_TIMESTAMP('2650000','J'); +SELECT TO_TIMESTAMP('2650000-2542','J-YYYY'); +SELECT TO_TIMESTAMP('2650000-2543','J-YYYY'); +SELECT TO_TIMESTAMP('2650000-4','J-MM'); +SELECT TO_TIMESTAMP('2650000-5','J-MM'); +SELECT TO_TIMESTAMP('2650000-8','J-DD'); +SELECT TO_TIMESTAMP('2650000-9','J-DD'); + +SELECT TO_TIMESTAMP('2012-245','YYYY-DDD'); +SELECT TO_TIMESTAMP('2012-245-8','YYYY-DDD-MM'); +SELECT TO_TIMESTAMP('2012-245-9','YYYY-DDD-MM'); +SELECT TO_TIMESTAMP('2012-245-1','YYYY-DDD-DD'); +SELECT TO_TIMESTAMP('2012-245-2','YYYY-DDD-DD'); +select TO_TIMESTAMP('2012-11-15','YYYY-MM-DD'); + +--MS +SELECT TO_TIMESTAMP('-1','MS'); +SELECT TO_TIMESTAMP('0','MS'); +SELECT TO_TIMESTAMP('256','MS'); +SELECT TO_TIMESTAMP('999','MS'); +SELECT TO_TIMESTAMP('1000','MS'); +--WW +SELECT TO_TIMESTAMP('0','WW'); +SELECT TO_TIMESTAMP('1','WW'); +SELECT TO_TIMESTAMP('10','WW'); +SELECT TO_TIMESTAMP('53','WW'); +SELECT TO_TIMESTAMP('54','WW'); +--D +SELECT TO_TIMESTAMP('0','D'); +SELECT TO_TIMESTAMP('1','D'); +SELECT TO_TIMESTAMP('4','D'); +SELECT TO_TIMESTAMP('7','D'); +SELECT TO_TIMESTAMP('8','D'); +--WW & D YYYY +SELECT TO_TIMESTAMP('2012-50-0','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-50-1','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-50-4','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-50-7','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-50-8','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-0-4','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-1-4','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-50-4','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-53-4','YYYY-WW-D'); +SELECT TO_TIMESTAMP('2012-54-4','YYYY-WW-D'); +--US +SELECT TO_TIMESTAMP('-1','US'); +SELECT TO_TIMESTAMP('0','US'); +SELECT TO_TIMESTAMP('99999','US'); +SELECT TO_TIMESTAMP('999999','US'); +SELECT TO_TIMESTAMP('1000000','US'); +--W +SELECT TO_TIMESTAMP('-1','W'); +SELECT TO_TIMESTAMP('0','W'); +SELECT TO_TIMESTAMP('1','W'); +SELECT TO_TIMESTAMP('5','W'); +SELECT TO_TIMESTAMP('6','W'); +--DCH_check +select TO_TIMESTAMP('13' ,'HH'); +select TO_TIMESTAMP('25','HH24'); +select TO_TIMESTAMP('62','MI'); +select TO_TIMESTAMP('62','SS'); +select TO_TIMESTAMP('86400','SSSSS'); +select TO_TIMESTAMP('8','D'); +select TO_TIMESTAMP('32','DD'); +select TO_TIMESTAMP('367','DDD'); +select TO_TIMESTAMP('36','MM'); +select TO_TIMESTAMP('1000','MS'); +select TO_TIMESTAMP('54','WW'); +select TO_TIMESTAMP('7','W'); +select TO_TIMESTAMP('5373485','J'); +select TO_TIMESTAMP('-1','US'); +select TO_TIMESTAMP('10000','SYYYY'); +select TO_TIMESTAMP('10000','RR'); + +SHOW nls_timestamp_format; + +SELECT TO_TIMESTAMP('0097/Feb/16 --> 08:14:30', 'YYYY/Mon/DD --> HH:MI:SS'); +SELECT TO_TIMESTAMP('97/2/16 8:14:30', 'FMYYYY/FMMM/FMDD FMHH:FMMI:FMSS'); +SELECT TO_TIMESTAMP('1985 January 12', 'YYYY FMMonth DD'); +SELECT TO_TIMESTAMP('My birthday-> Year: 1976, Month: May, Day: 16', + '"My birthday-> Year" YYYY, "Month:" FMMonth, "Day:" DD'); +SELECT TO_TIMESTAMP('1,582nd VIII 21', 'Y,YYYth FMRM DD'); +SELECT TO_TIMESTAMP('15 "text between quote marks" 98 54 45', + E'HH24 "\\text between quote marks\\"" YY MI SS'); +SELECT TO_TIMESTAMP('05121445482000', 'MMDDHH24MISSYYYY'); +SELECT TO_TIMESTAMP('2000January09Sunday', 'YYYYFMMonthDDFMDay'); +SELECT TO_TIMESTAMP('97/Feb/16', 'YYMonDD'); +SELECT TO_TIMESTAMP('19971116', 'YYYYMMDD'); +SELECT TO_TIMESTAMP('20000-1116', 'YYYY-MMDD'); +SELECT TO_TIMESTAMP('9-1116', 'Y-MMDD'); +SELECT TO_TIMESTAMP('95-1116', 'YY-MMDD'); +SELECT TO_TIMESTAMP('995-1116', 'YYY-MMDD'); +SELECT TO_TIMESTAMP('2005426', 'YYYYWWD'); +SELECT TO_TIMESTAMP('2005300', 'YYYYDDD'); +SELECT TO_TIMESTAMP('2005527', 'IYYYIWID'); +SELECT TO_TIMESTAMP('005527', 'IYYIWID'); +SELECT TO_TIMESTAMP('05527', 'IYIWID'); +SELECT TO_TIMESTAMP('5527', 'IIWID'); +SELECT TO_TIMESTAMP('2005364', 'IYYYIDDD'); +SELECT TO_TIMESTAMP('20050302', 'YYYYMMDD'); +SELECT TO_TIMESTAMP('2005 03 02', 'YYYYMMDD'); +SELECT TO_TIMESTAMP(' 2005 03 02', 'YYYYMMDD'); +SELECT TO_TIMESTAMP(' 20050302', 'YYYYMMDD'); + +SHOW nls_timestamp_format; +select TO_TIMESTAMP('9999-3-4 13:2:3.234015'); -- error: ERROR: invalid data for "hour = 13" ,value must be between 1 and 12 + +SHOW nls_timestamp_format; +-- with default +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT NULL ON CONVERSION ERROR); +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT '1,582nd VIII 21' ON CONVERSION ERROR); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT 'abc' ON CONVERSION ERROR); +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT 3.14 ON CONVERSION ERROR); -- error: ERROR: invalid data for "month = 14" ,value must be between 1 and 12 +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT '2010-01-01 01:00:00' ON CONVERSION ERROR); + +--------------------------------------------- +--------- 24-hour clock(DEFAULT FMT) -------- +--------------------------------------------- +SET nls_timestamp_format = 'YYYY-MM-DD HH:MI:SS'; +SHOW nls_timestamp_format; + +SELECT TO_TIMESTAMP('1998'); +SELECT TO_TIMESTAMP('1998-12-28'); +SELECT TO_TIMESTAMP('1998-12-28 01'); +SELECT TO_TIMESTAMP('1998-12-28 01:02'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12'); +SELECT TO_TIMESTAMP('1998-12-28 01:02:03.12 AM'); +SELECT TO_TIMESTAMP('1998-12-28 11:12:13 PM'); +SELECT TO_TIMESTAMP('01'); + +SELECT TO_TIMESTAMP('01'); +SELECT TO_TIMESTAMP('01-Sep'); +SELECT TO_TIMESTAMP('01-Sep-1998'); +SELECT TO_TIMESTAMP('01-Sep-1998 11'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13.12 PM'); +SELECT TO_TIMESTAMP('01-Sep-1998 11:12:13 PM'); +SELECT TO_TIMESTAMP('01-Sep-1998 16:12:13'); +SELECT TO_TIMESTAMP('01-Sep-1998 12:55:66'); +SELECT TO_TIMESTAMP('01-Sep-1998 24:12:13'); +SELECT TO_TIMESTAMP('01-Sep-1998 25:55:66'); +SELECT TO_TIMESTAMP('01-Sep-1998 60:12:13'); +SELECT TO_TIMESTAMP('01-Sep-1998 12:60:00'); + +--------------------------------------------- +--------- DEFINE FMT -------- +--------------------------------------------- + +-- SET DateStyle TO 'ISO, MDY'; +select TO_TIMESTAMP('23 01 01','hh24 mi ss'); +select TO_TIMESTAMP('20150101 232323','yyyymmdd hh24miss'); +select TO_TIMESTAMP('20150101 232323','yyyymmdd hh24miss'); +SELECT TO_TIMESTAMP('0','HH24'); +SELECT TO_TIMESTAMP('23','HH24'); +SELECT TO_TIMESTAMP('24','HH24'); +SELECT TO_TIMESTAMP('24','H24'); +select TO_TIMESTAMP('10','H24'); +select TO_TIMESTAMP('10','H24'); + +SELECT TO_TIMESTAMP('1,582nd VIII 21', 'Y,YYYth FMRM DD'); +SELECT TO_TIMESTAMP('-2012-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +SELECT TO_TIMESTAMP('-1-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +SELECT TO_TIMESTAMP('0-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +SELECT TO_TIMESTAMP('9999-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); +SELECT TO_TIMESTAMP('10000-2/3,21.15;36:18','YYYY-MM/DD,HH24.MI;SS:FF'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'syyyy-mm-dd hh24:mi:ss.ff'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'SYYYY-mm-dd hh24:mi:ss.ff'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'RR-mm-dd hh24:mi:ss.ff'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'RRRR-mm-dd hh24:mi:ss.ff'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'rr-mm-dd hh24:mi:ss.ff'); + +select TO_TIMESTAMP('-4713-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-4712-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('-1-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('0-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('1-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015', 'rrrr-mm-dd hh24:mi:ss.ff'); + +-- Mixture of date conventions (ISO week and Gregorian): +SELECT TO_TIMESTAMP('2005527', 'YYYYIWID'); -- error: Do not mix Gregorian and ISO week date conventions in a formatting template. +-- Insufficient characters in the source string: +SELECT TO_TIMESTAMP('19971', 'YYYYMMDD'); -- error: Field requires 2 characters, but only 1 remain. +-- Insufficient digit characters for a single node: +SELECT TO_TIMESTAMP('19971)24', 'YYYYMMDD'); -- error; invalid value "1)" for "MM" +-- Value clobbering: +SELECT TO_TIMESTAMP('1997-11-Jan-16', 'YYYY-MM-Mon-DD'); -- error; conflicting values for "Mon" field in formatting string +-- Non-numeric input: +SELECT TO_TIMESTAMP('199711xy', 'YYYYMMDD'); -- error: invalid value "xy" for "DD" +-- Input that doesn't fit in an int: +SELECT TO_TIMESTAMP('10000000000', 'FMYYYY'); -- error: value for "YYYY" in source string is out of range. +SELECT TO_TIMESTAMP('2010-01-01 00:00:00','yyyy-mm-dd hh24:mi:ss'); + +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT '1,582nd VIII 21' ON CONVERSION ERROR, 'Y,YYYth FMRM DD'); +SELECT TO_TIMESTAMP('1,582nd VIII 66' DEFAULT 'abcdefg' ON CONVERSION ERROR, 'Y,YYYth FMRM DD'); +SELECT TO_TIMESTAMP('2012-245-2' DEFAULT 3.14 ON CONVERSION ERROR,'YYYY-DDD-DD'); +select TO_TIMESTAMP('2012-11-15' DEFAULT NULL ON CONVERSION ERROR,'YYYY-MM-DD'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('9999-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT '2012-11-15' ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT 3.14 ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); +select TO_TIMESTAMP('10000-3-4 13:2:3.234015' DEFAULT NULL ON CONVERSION ERROR, 'RR-mm-dd hh24:mi:ss.ff'); + +-- USE TO_TIMESTAMP CHECKDAYS +SELECT (TO_TIMESTAMP('12:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')) * 24 *3600; +SELECT (TO_TIMESTAMP('18:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')) + (TO_TIMESTAMP('15:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('11:59:04', 'hh24:mi:ss.sssss')); +SELECT (TO_TIMESTAMP('23:59:04', 'hh24:mi:ss') - TO_TIMESTAMP('00:34:04', 'hh24:mi:ss.sssss')) + (TO_TIMESTAMP('22:38:13', 'hh24:mi:ss') - TO_TIMESTAMP('02:45:53', 'hh24:mi:ss.sssss')); +--DAY > 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-5 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 02:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss')); +SELECT ((TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-5 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-2 02:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss'))) * 2; +--DAY < 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 20:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss')); +SELECT ((TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-7 20:45:53', 'YYYY-MM-DD hh24:mi:ss.sssss'))) * 2; +--DAY > 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-8 22:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-4 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY = 0 && TIME > 0 +SELECT (TO_TIMESTAMP('2012-8-5 23:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 00:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 00:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 23:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY < 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 23:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-3 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY = 0 && TIME < 0 +SELECT (TO_TIMESTAMP('2012-8-5 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-5 23:34:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 23:38:13', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY > 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-1 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) - (TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY < 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-3 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss')); +--DAY = 0 && TIME = 0 +SELECT (TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:59:04', 'YYYY-MM-DD hh24:mi:ss.sssss')) + (TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss') - TO_TIMESTAMP('2012-8-8 00:11:23', 'YYYY-MM-DD hh24:mi:ss.sssss'));