From b40213b0d31b8ac55cda4658c21d06e701b6e273 Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Tue, 15 Dec 2020 14:27:58 +0100 Subject: [PATCH v4] Change return type of EXTRACT to numeric The previous implementation of EXTRACT mapped internally to date_part(), which returned type double precision (since it was implemented long before the numeric type existed). This can lead to imprecise output in some cases, so returning numeric would be preferrable. Changing the return type of an existing function is a bit risky, so instead we do the following: We implement a new set of functions, which are now called "extract", in parallel to the existing date_part functions. They work the same way internally but use numeric instead of float8. The EXTRACT construct is now mapped by the parser to these new extract functions. That way, dumps of views etc. from old versions (which would use date_part) continue to work unchanged, but new uses will map to the new extract functions. Additionally, the reverse compilation of EXTRACT now reproduces the original syntax, using the new mechanism introduced in 40c24bfef92530bd846e111c1742c2a54441c62c. The following minor changes of behavior result from the new implementation: - The column name from an isolated EXTRACT call is now "extract" instead of "date_part". - Extract from date now rejects inappropriate field names such as HOUR. It was previously mapped internally to extract from timestamp, so it would silently accept everything appropriate for timestamp. - Return values when extracting fields with possibly fractional values, such as second and epoch, now have the full scale that the value has internally (so, for example, '1.000000' instead of just '1'). Discussion: https://www.postgresql.org/message-id/flat/42b73d2d-da12-ba9f-570a-420e0cce19d9@phystech.edu --- doc/src/sgml/func.sgml | 10 +- src/backend/parser/gram.y | 2 +- src/backend/utils/adt/date.c | 407 +++++++++++ src/backend/utils/adt/ruleutils.c | 21 + src/backend/utils/adt/timestamp.c | 708 +++++++++++++++++++- src/include/catalog/pg_proc.dat | 18 + src/test/regress/expected/create_view.out | 2 +- src/test/regress/expected/date.out | 482 ++++++------- src/test/regress/expected/interval.out | 72 +- src/test/regress/expected/psql_crosstab.out | 12 +- src/test/regress/expected/time.out | 24 +- src/test/regress/expected/timetz.out | 42 +- src/test/regress/sql/date.sql | 6 +- 13 files changed, 1445 insertions(+), 361 deletions(-) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index df29af6371..a42993c4a5 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -8705,7 +8705,7 @@ Date/Time Functions extract extract ( field from timestamp ) - double precision + numeric Get timestamp subfield; see @@ -8719,7 +8719,7 @@ Date/Time Functions extract ( field from interval ) - double precision + numeric Get interval subfield; see @@ -9234,7 +9234,7 @@ <function>EXTRACT</function>, <function>date_part</function> well.) field is an identifier or string that selects what field to extract from the source value. The extract function returns values of type - double precision. + numeric. The following are valid field names: @@ -9645,6 +9645,10 @@ <function>EXTRACT</function>, <function>date_part</function> be a string value, not a name. The valid field names for date_part are the same as for extract. + For historical reasons, the date_part function + returns values of type double precision. This can result in + a loss of precision in certain uses. Using extract + is recommended instead. diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 8f341ac006..2e8924aff8 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -13768,7 +13768,7 @@ func_expr_common_subexpr: { $$ = makeTypeCast($3, $5, @1); } | EXTRACT '(' extract_list ')' { - $$ = (Node *) makeFuncCall(SystemFuncName("date_part"), + $$ = (Node *) makeFuncCall(SystemFuncName("extract"), $3, COERCE_SQL_SYNTAX, @1); diff --git a/src/backend/utils/adt/date.c b/src/backend/utils/adt/date.c index a470cf890a..61fd69829c 100644 --- a/src/backend/utils/adt/date.c +++ b/src/backend/utils/adt/date.c @@ -31,6 +31,7 @@ #include "utils/builtins.h" #include "utils/date.h" #include "utils/datetime.h" +#include "utils/numeric.h" #include "utils/sortsupport.h" /* @@ -1063,6 +1064,180 @@ in_range_date_interval(PG_FUNCTION_ARGS) } +/* extract_date() + * Extract specified field from date type. + */ +Datum +extract_date(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + DateADT date = PG_GETARG_DATEADT(1); + int64 result; + int type, + val; + char *lowunits; + int year, mon, mday; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (DATE_NOT_FINITE(date) && (type == UNITS || type == RESERV)) + { + switch (val) + { + /* Oscillating units */ + case DTK_DAY: + case DTK_MONTH: + case DTK_QUARTER: + case DTK_WEEK: + case DTK_DOW: + case DTK_ISODOW: + case DTK_DOY: + PG_RETURN_NULL(); + break; + + /* Monotonically-increasing units */ + case DTK_YEAR: + case DTK_DECADE: + case DTK_CENTURY: + case DTK_MILLENNIUM: + case DTK_JULIAN: + case DTK_ISOYEAR: + case DTK_EPOCH: + if (DATE_IS_NOBEGIN(date)) + PG_RETURN_NUMERIC(DatumGetNumeric(DirectFunctionCall3(numeric_in, + CStringGetDatum("-Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1)))); + else + PG_RETURN_NUMERIC(DatumGetNumeric(DirectFunctionCall3(numeric_in, + CStringGetDatum("Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1)))); + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("date units \"%s\" not supported", + lowunits))); + } + } + else if (type == UNITS) + { + j2date(date + POSTGRES_EPOCH_JDATE, &year, &mon, &mday); + + switch (val) + { + case DTK_DAY: + result = mday; + break; + + case DTK_MONTH: + result = mon; + break; + + case DTK_QUARTER: + result = (mon - 1) / 3 + 1; + break; + + case DTK_WEEK: + result = date2isoweek(year, mon, mday); + break; + + case DTK_YEAR: + if (year > 0) + result = year; + else + /* there is no year 0, just 1 BC and 1 AD */ + result = year - 1; + break; + + case DTK_DECADE: + /* see comments in timestamp_part */ + if (year >= 0) + result = year / 10; + else + result = -((8 - (year - 1)) / 10); + break; + + case DTK_CENTURY: + /* see comments in timestamp_part */ + if (year > 0) + result = (year + 99) / 100; + else + result = -((99 - (year - 1)) / 100); + break; + + case DTK_MILLENNIUM: + /* see comments in timestamp_part */ + if (year > 0) + result = (year + 999) / 1000; + else + result = -((999 - (year - 1)) / 1000); + break; + + case DTK_JULIAN: + result = date + POSTGRES_EPOCH_JDATE; + break; + + case DTK_ISOYEAR: + result = date2isoyear(year, mon, mday); + /* Adjust BC years */ + if (result <= 0) + result -= 1; + break; + + case DTK_DOW: + case DTK_ISODOW: + result = j2day(date + POSTGRES_EPOCH_JDATE); + if (val == DTK_ISODOW && result == 0) + result = 7; + break; + + case DTK_DOY: + result = date2j(year, mon, mday) - date2j(year, 1, 1) + 1; + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("date units \"%s\" not supported", + lowunits))); + result = 0; + } + } + else if (type == RESERV) + { + switch (val) + { + case DTK_EPOCH: + result = ((int64) date + POSTGRES_EPOCH_JDATE - UNIX_EPOCH_JDATE) * SECS_PER_DAY; + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("date units \"%s\" not supported", + lowunits))); + result = 0; + } + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("date units \"%s\" not recognized", lowunits))); + result = 0; + } + + PG_RETURN_NUMERIC(int64_to_numeric(result)); +} + + /* Add an interval to a date, giving a new date. * Must handle both positive and negative intervals. * @@ -2036,6 +2211,114 @@ time_part(PG_FUNCTION_ARGS) } +/* extract_time() + * Extract specified field from time type. + */ +Datum +extract_time(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + TimeADT time = PG_GETARG_TIMEADT(1); + Numeric result; + int type, + val; + char *lowunits; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (type == UNITS) + { + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + + time2tm(time, tm, &fsec); + + switch (val) + { + case DTK_MICROSEC: + result = int64_to_numeric(tm->tm_sec * 1000000 + fsec); + break; + + case DTK_MILLISEC: + /* tm->tm_sec * 1000 + fsec / 1000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec * 1000), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(3))); + break; + + case DTK_SECOND: + /* tm->tm_sec + fsec / 1000000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + case DTK_MINUTE: + result = int64_to_numeric(tm->tm_min); + break; + + case DTK_HOUR: + result = int64_to_numeric(tm->tm_hour); + break; + + case DTK_TZ: + case DTK_TZ_MINUTE: + case DTK_TZ_HOUR: + case DTK_DAY: + case DTK_MONTH: + case DTK_QUARTER: + case DTK_YEAR: + case DTK_DECADE: + case DTK_CENTURY: + case DTK_MILLENNIUM: + case DTK_ISOYEAR: + default: + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\"time\" units \"%s\" not recognized", + lowunits))); + result = 0; + } + } + else if (type == RESERV && val == DTK_EPOCH) + { + result = numeric_div_opt_error(int64_to_numeric(time), + int64_to_numeric(1000000), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\"time\" units \"%s\" not recognized", + lowunits))); + result = 0; + } + + PG_RETURN_NUMERIC(result); +} + + /***************************************************************************** * Time With Time Zone ADT *****************************************************************************/ @@ -2785,6 +3068,130 @@ timetz_part(PG_FUNCTION_ARGS) PG_RETURN_FLOAT8(result); } + +/* timetz_part() + * Extract specified field from time type. + */ +Datum +extract_timetz(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + TimeTzADT *time = PG_GETARG_TIMETZADT_P(1); + Numeric result; + int type, + val; + char *lowunits; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (type == UNITS) + { + int tz; + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + + timetz2tm(time, tm, &fsec, &tz); + + switch (val) + { + case DTK_TZ: + result = int64_to_numeric(-tz); + break; + + case DTK_TZ_MINUTE: + /* trunc(-tz / 60) % 60 */ + result = numeric_mod_opt_error(int64_to_numeric(-tz / SECS_PER_MINUTE), + int64_to_numeric(SECS_PER_MINUTE), + NULL); + break; + + case DTK_TZ_HOUR: + result = int64_to_numeric(-tz / SECS_PER_HOUR); + break; + + case DTK_MICROSEC: + result = int64_to_numeric(tm->tm_sec * 1000000 + fsec); + break; + + case DTK_MILLISEC: + /* tm->tm_sec * 1000 + fsec / 1000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec * 1000), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(3))); + break; + + case DTK_SECOND: + /* tm->tm_sec + fsec / 1000000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + case DTK_MINUTE: + result = int64_to_numeric(tm->tm_min); + break; + + case DTK_HOUR: + result = int64_to_numeric(tm->tm_hour); + break; + + case DTK_DAY: + case DTK_MONTH: + case DTK_QUARTER: + case DTK_YEAR: + case DTK_DECADE: + case DTK_CENTURY: + case DTK_MILLENNIUM: + default: + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\"time with time zone\" units \"%s\" not recognized", + lowunits))); + result = 0; + } + } + else if (type == RESERV && val == DTK_EPOCH) + { + /* time->time / 1000000.0 + time->zone */ + result = numeric_add_opt_error(numeric_div_opt_error(int64_to_numeric(time->time), + int64_to_numeric(1000000), + NULL), + int64_to_numeric(time->zone), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("\"time with time zone\" units \"%s\" not recognized", + lowunits))); + result = 0; + } + + PG_RETURN_NUMERIC(result); +} + + /* timetz_zone() * Encode time with time zone type with specified time zone. * Applies DST rules as of the current date. diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index ad582f99a5..d312dfa756 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -9556,6 +9556,27 @@ get_func_sql_syntax(FuncExpr *expr, deparse_context *context) appendStringInfoString(buf, "))"); return true; + case F_EXTRACT_TEXT_DATE: + case F_EXTRACT_TEXT_TIME: + case F_EXTRACT_TEXT_TIMETZ: + case F_EXTRACT_TEXT_TIMESTAMP: + case F_EXTRACT_TEXT_TIMESTAMPTZ: + case F_EXTRACT_TEXT_INTERVAL: + /* EXTRACT (x FROM y) */ + appendStringInfoString(buf, "EXTRACT("); + { + Const *con = (Const *) linitial(expr->args); + + Assert(IsA(con, Const) && + con->consttype == TEXTOID && + !con->constisnull); + appendStringInfoString(buf, TextDatumGetCString(con->constvalue)); + } + appendStringInfoString(buf, " FROM "); + get_rule_expr((Node *) lsecond(expr->args), context, false); + appendStringInfoChar(buf, ')'); + return true; + case F_IS_NORMALIZED: /* IS xxx NORMALIZED */ appendStringInfoString(buf, "(("); diff --git a/src/backend/utils/adt/timestamp.c b/src/backend/utils/adt/timestamp.c index 2dbd309122..4c643033ad 100644 --- a/src/backend/utils/adt/timestamp.c +++ b/src/backend/utils/adt/timestamp.c @@ -35,6 +35,7 @@ #include "utils/date.h" #include "utils/datetime.h" #include "utils/float.h" +#include "utils/numeric.h" /* * gcc's -ffast-math switch breaks routines that expect exact results from @@ -4447,7 +4448,7 @@ date2isoyearday(int year, int mon, int mday) } /* - * NonFiniteTimestampTzPart + * NonFiniteTimestampTzPart_float8 * * Used by timestamp_part and timestamptz_part when extracting from infinite * timestamp[tz]. Returns +/-Infinity if that is the appropriate result, @@ -4458,8 +4459,8 @@ date2isoyearday(int year, int mon, int mday) * discrepancies between finite- and infinite-input cases. */ static float8 -NonFiniteTimestampTzPart(int type, int unit, char *lowunits, - bool isNegative, bool isTz) +NonFiniteTimestampTzPart_float8(int type, int unit, char *lowunits, + bool isNegative, bool isTz) { if ((type != UNITS) && (type != RESERV)) { @@ -4523,6 +4524,89 @@ NonFiniteTimestampTzPart(int type, int unit, char *lowunits, } } +/* + * NonFiniteTimestampTzPart_numeric + * + * Used by extract_timestamp and extract_timestamptz when extracting from infinite + * timestamp[tz]. Returns +/-Infinity if that is the appropriate result, + * otherwise returns NULL (which should be taken as meaning to return SQL NULL). + * + * Errors thrown here for invalid units should exactly match those that + * would be thrown in the calling functions, else there will be unexpected + * discrepancies between finite- and infinite-input cases. + */ +static Numeric +NonFiniteTimestampTzPart_numeric(int type, int unit, char *lowunits, + bool isNegative, bool isTz) +{ + if ((type != UNITS) && (type != RESERV)) + { + if (isTz) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("timestamp with time zone units \"%s\" not recognized", + lowunits))); + else + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("timestamp units \"%s\" not recognized", + lowunits))); + } + + switch (unit) + { + /* Oscillating units */ + case DTK_MICROSEC: + case DTK_MILLISEC: + case DTK_SECOND: + case DTK_MINUTE: + case DTK_HOUR: + case DTK_DAY: + case DTK_MONTH: + case DTK_QUARTER: + case DTK_WEEK: + case DTK_DOW: + case DTK_ISODOW: + case DTK_DOY: + case DTK_TZ: + case DTK_TZ_MINUTE: + case DTK_TZ_HOUR: + return NULL; + + /* Monotonically-increasing units */ + case DTK_YEAR: + case DTK_DECADE: + case DTK_CENTURY: + case DTK_MILLENNIUM: + case DTK_JULIAN: + case DTK_ISOYEAR: + case DTK_EPOCH: + if (isNegative) + return DatumGetNumeric(DirectFunctionCall3(numeric_in, + CStringGetDatum("-Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1))); + else + return DatumGetNumeric(DirectFunctionCall3(numeric_in, + CStringGetDatum("Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1))); + + default: + if (isTz) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp with time zone units \"%s\" not supported", + lowunits))); + else + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp units \"%s\" not supported", + lowunits))); + return NULL; /* keep compiler quiet */ + } +} + /* timestamp_part() * Extract specified field from timestamp. */ @@ -4550,9 +4634,9 @@ timestamp_part(PG_FUNCTION_ARGS) if (TIMESTAMP_NOT_FINITE(timestamp)) { - result = NonFiniteTimestampTzPart(type, val, lowunits, - TIMESTAMP_IS_NOBEGIN(timestamp), - false); + result = NonFiniteTimestampTzPart_float8(type, val, lowunits, + TIMESTAMP_IS_NOBEGIN(timestamp), + false); if (result) PG_RETURN_FLOAT8(result); else @@ -4717,6 +4801,237 @@ timestamp_part(PG_FUNCTION_ARGS) PG_RETURN_FLOAT8(result); } +/* extract_timestamp() + * Extract specified field from timestamp. + */ +Datum +extract_timestamp(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + Timestamp timestamp = PG_GETARG_TIMESTAMP(1); + Numeric result; + Timestamp epoch; + int type, + val; + char *lowunits; + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (TIMESTAMP_NOT_FINITE(timestamp)) + { + result = NonFiniteTimestampTzPart_numeric(type, val, lowunits, + TIMESTAMP_IS_NOBEGIN(timestamp), + false); + if (result) + PG_RETURN_NUMERIC(result); + else + PG_RETURN_NULL(); + } + + if (type == UNITS) + { + if (timestamp2tm(timestamp, NULL, tm, &fsec, NULL, NULL) != 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + + switch (val) + { + case DTK_MICROSEC: + result = int64_to_numeric(tm->tm_sec * 1000000 + fsec); + break; + + case DTK_MILLISEC: + /* tm->tm_sec * 1000 + fsec / 1000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec * 1000), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(3))); + break; + + case DTK_SECOND: + /* tm->tm_sec + fsec / 1000000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + case DTK_MINUTE: + result = int64_to_numeric(tm->tm_min); + break; + + case DTK_HOUR: + result = int64_to_numeric(tm->tm_hour); + break; + + case DTK_DAY: + result = int64_to_numeric(tm->tm_mday); + break; + + case DTK_MONTH: + result = int64_to_numeric(tm->tm_mon); + break; + + case DTK_QUARTER: + result = int64_to_numeric((tm->tm_mon - 1) / 3 + 1); + break; + + case DTK_WEEK: + result = int64_to_numeric(date2isoweek(tm->tm_year, tm->tm_mon, tm->tm_mday)); + break; + + case DTK_YEAR: + if (tm->tm_year > 0) + result = int64_to_numeric(tm->tm_year); + else + /* there is no year 0, just 1 BC and 1 AD */ + result = int64_to_numeric(tm->tm_year - 1); + break; + + case DTK_DECADE: + + /* + * what is a decade wrt dates? let us assume that decade 199 + * is 1990 thru 1999... decade 0 starts on year 1 BC, and -1 + * is 11 BC thru 2 BC... + */ + if (tm->tm_year >= 0) + result = int64_to_numeric(tm->tm_year / 10); + else + result = int64_to_numeric(-((8 - (tm->tm_year - 1)) / 10)); + break; + + case DTK_CENTURY: + + /* ---- + * centuries AD, c>0: year in [ (c-1)* 100 + 1 : c*100 ] + * centuries BC, c<0: year in [ c*100 : (c+1) * 100 - 1] + * there is no number 0 century. + * ---- + */ + if (tm->tm_year > 0) + result = int64_to_numeric((tm->tm_year + 99) / 100); + else + /* caution: C division may have negative remainder */ + result = int64_to_numeric(-((99 - (tm->tm_year - 1)) / 100)); + break; + + case DTK_MILLENNIUM: + /* see comments above. */ + if (tm->tm_year > 0) + result = int64_to_numeric((tm->tm_year + 999) / 1000); + else + result = int64_to_numeric(-((999 - (tm->tm_year - 1)) / 1000)); + break; + + case DTK_JULIAN: + result = numeric_add_opt_error( + int64_to_numeric(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday)), + numeric_div_opt_error( + int64_to_numeric(((((tm->tm_hour * MINS_PER_HOUR) + tm->tm_min) * SECS_PER_MINUTE) + tm->tm_sec) * 1000000LL + fsec), + int64_to_numeric(SECS_PER_DAY * 1000000LL), + NULL), + NULL); + break; + + case DTK_ISOYEAR: + { + int tmp = date2isoyear(tm->tm_year, tm->tm_mon, tm->tm_mday); + /* Adjust BC years */ + if (tmp <= 0) + tmp -= 1; + result = int64_to_numeric(tmp); + break; + } + + case DTK_DOW: + case DTK_ISODOW: + { + int tmp = j2day(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday)); + if (val == DTK_ISODOW && tmp == 0) + tmp = 7; + result = int64_to_numeric(tmp); + break; + } + + case DTK_DOY: + result = int64_to_numeric(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday) + - date2j(tm->tm_year, 1, 1) + 1); + break; + + case DTK_TZ: + case DTK_TZ_MINUTE: + case DTK_TZ_HOUR: + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp units \"%s\" not supported", + lowunits))); + result = 0; + } + } + else if (type == RESERV) + { + switch (val) + { + case DTK_EPOCH: + /* (timestamp - epoch) / 1000000 */ + epoch = SetEpochTimestamp(); + if (timestamp < (PG_INT64_MAX + epoch)) + result = numeric_div_opt_error( + int64_to_numeric(timestamp - epoch), + int64_to_numeric(1000000), + NULL); + else + result = numeric_div_opt_error( + numeric_sub_opt_error(int64_to_numeric(timestamp), + int64_to_numeric(epoch), + NULL), + int64_to_numeric(1000000), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp units \"%s\" not supported", + lowunits))); + result = 0; + } + + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("timestamp units \"%s\" not recognized", lowunits))); + result = 0; + } + + PG_RETURN_NUMERIC(result); +} + /* timestamptz_part() * Extract specified field from timestamp with time zone. */ @@ -4746,9 +5061,9 @@ timestamptz_part(PG_FUNCTION_ARGS) if (TIMESTAMP_NOT_FINITE(timestamp)) { - result = NonFiniteTimestampTzPart(type, val, lowunits, - TIMESTAMP_IS_NOBEGIN(timestamp), - true); + result = NonFiniteTimestampTzPart_float8(type, val, lowunits, + TIMESTAMP_IS_NOBEGIN(timestamp), + true); if (result) PG_RETURN_FLOAT8(result); else @@ -4915,6 +5230,240 @@ timestamptz_part(PG_FUNCTION_ARGS) PG_RETURN_FLOAT8(result); } +/* extract_timestamptz() + * Extract specified field from timestamp with time zone. + */ +Datum +extract_timestamptz(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(1); + Numeric result; + Timestamp epoch; + int tz; + int type, + val; + char *lowunits; + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (TIMESTAMP_NOT_FINITE(timestamp)) + { + result = NonFiniteTimestampTzPart_numeric(type, val, lowunits, + TIMESTAMP_IS_NOBEGIN(timestamp), + true); + if (result) + PG_RETURN_NUMERIC(result); + else + PG_RETURN_NULL(); + } + + if (type == UNITS) + { + if (timestamp2tm(timestamp, &tz, tm, &fsec, NULL, NULL) != 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + + switch (val) + { + case DTK_TZ: + result = int64_to_numeric(-tz); + break; + + case DTK_TZ_MINUTE: + /* trunc(-tz / 60) % 60 */ + result = numeric_mod_opt_error(int64_to_numeric(-tz / SECS_PER_MINUTE), + int64_to_numeric(SECS_PER_MINUTE), + NULL); + break; + + case DTK_TZ_HOUR: + result = int64_to_numeric(-tz / SECS_PER_HOUR); + break; + + case DTK_MICROSEC: + result = int64_to_numeric(tm->tm_sec * 1000000 + fsec); + break; + + case DTK_MILLISEC: + /* tm->tm_sec * 1000 + fsec / 1000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec * 1000), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(3))); + break; + + case DTK_SECOND: + /* tm->tm_sec + fsec / 1000000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + case DTK_MINUTE: + result = int64_to_numeric(tm->tm_min); + break; + + case DTK_HOUR: + result = int64_to_numeric(tm->tm_hour); + break; + + case DTK_DAY: + result = int64_to_numeric(tm->tm_mday); + break; + + case DTK_MONTH: + result = int64_to_numeric(tm->tm_mon); + break; + + case DTK_QUARTER: + result = int64_to_numeric((tm->tm_mon - 1) / 3 + 1); + break; + + case DTK_WEEK: + result = int64_to_numeric(date2isoweek(tm->tm_year, tm->tm_mon, tm->tm_mday)); + break; + + case DTK_YEAR: + if (tm->tm_year > 0) + result = int64_to_numeric(tm->tm_year); + else + /* there is no year 0, just 1 BC and 1 AD */ + result = int64_to_numeric(tm->tm_year - 1); + break; + + case DTK_DECADE: + /* see comments in timestamp_part */ + if (tm->tm_year >= 0) + result = int64_to_numeric(tm->tm_year / 10); + else + result = int64_to_numeric(-((8 - (tm->tm_year - 1)) / 10)); + break; + + case DTK_CENTURY: + /* see comments in timestamp_part */ + if (tm->tm_year > 0) + result = int64_to_numeric((tm->tm_year + 99) / 100); + else + result = int64_to_numeric(-((99 - (tm->tm_year - 1)) / 100)); + break; + + case DTK_MILLENNIUM: + /* see comments in timestamp_part */ + if (tm->tm_year > 0) + result = int64_to_numeric((tm->tm_year + 999) / 1000); + else + result = int64_to_numeric(-((999 - (tm->tm_year - 1)) / 1000)); + break; + + case DTK_JULIAN: + result = numeric_add_opt_error( + int64_to_numeric(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday)), + numeric_div_opt_error( + int64_to_numeric(((((tm->tm_hour * MINS_PER_HOUR) + tm->tm_min) * SECS_PER_MINUTE) + tm->tm_sec) * 1000000LL + fsec), + int64_to_numeric(SECS_PER_DAY * 1000000LL), + NULL), + NULL); + break; + + case DTK_ISOYEAR: + { + int tmp = date2isoyear(tm->tm_year, tm->tm_mon, tm->tm_mday); + /* Adjust BC years */ + if (tmp <= 0) + tmp -= 1; + result = int64_to_numeric(tmp); + break; + } + + case DTK_DOW: + case DTK_ISODOW: + { + int tmp = j2day(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday)); + if (val == DTK_ISODOW && tmp == 0) + tmp = 7; + result = int64_to_numeric(tmp); + break; + } + + case DTK_DOY: + result = int64_to_numeric(date2j(tm->tm_year, tm->tm_mon, tm->tm_mday) + - date2j(tm->tm_year, 1, 1) + 1); + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp with time zone units \"%s\" not supported", + lowunits))); + result = 0; + } + + } + else if (type == RESERV) + { + switch (val) + { + case DTK_EPOCH: + /* (timestamp - epoch) / 1000000 */ + epoch = SetEpochTimestamp(); + if (timestamp < (PG_INT64_MAX + epoch)) + result = numeric_div_opt_error( + int64_to_numeric(timestamp - epoch), + int64_to_numeric(1000000), + NULL); + else + result = numeric_div_opt_error( + numeric_sub_opt_error(int64_to_numeric(timestamp), + int64_to_numeric(epoch), + NULL), + int64_to_numeric(1000000), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("timestamp with time zone units \"%s\" not supported", + lowunits))); + result = 0; + } + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("timestamp with time zone units \"%s\" not recognized", + lowunits))); + + result = 0; + } + + PG_RETURN_NUMERIC(result); +} + /* interval_part() * Extract specified field from interval. @@ -5032,6 +5581,147 @@ interval_part(PG_FUNCTION_ARGS) } +/* extract_interval() + * Extract specified field from interval. + */ +Datum +extract_interval(PG_FUNCTION_ARGS) +{ + text *units = PG_GETARG_TEXT_PP(0); + Interval *interval = PG_GETARG_INTERVAL_P(1); + Numeric result; + int type, + val; + char *lowunits; + fsec_t fsec; + struct pg_tm tt, + *tm = &tt; + + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), + VARSIZE_ANY_EXHDR(units), + false); + + type = DecodeUnits(0, lowunits, &val); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(0, lowunits, &val); + + if (type == UNITS) + { + if (interval2tm(*interval, tm, &fsec) == 0) + { + switch (val) + { + case DTK_MICROSEC: + /* tm->tm_sec * 1000000 + fsec */ + result = int64_to_numeric(tm->tm_sec * 1000000 + fsec); + break; + + case DTK_MILLISEC: + /* tm->tm_sec * 1000 + fsec / 1000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec * 1000), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(3))); + break; + + case DTK_SECOND: + /* tm->tm_sec + fsec / 1000000 */ + result = numeric_add_opt_error(int64_to_numeric(tm->tm_sec), + numeric_div_opt_error(int64_to_numeric(fsec), + int64_to_numeric(1000000), + NULL), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + break; + + case DTK_MINUTE: + result = int64_to_numeric(tm->tm_min); + break; + + case DTK_HOUR: + result = int64_to_numeric(tm->tm_hour); + break; + + case DTK_DAY: + result = int64_to_numeric(tm->tm_mday); + break; + + case DTK_MONTH: + result = int64_to_numeric(tm->tm_mon); + break; + + case DTK_QUARTER: + result = int64_to_numeric((tm->tm_mon / 3) + 1); + break; + + case DTK_YEAR: + result = int64_to_numeric(tm->tm_year); + break; + + case DTK_DECADE: + /* caution: C division may have negative remainder */ + result = int64_to_numeric(tm->tm_year / 10); + break; + + case DTK_CENTURY: + /* caution: C division may have negative remainder */ + result = int64_to_numeric(tm->tm_year / 100); + break; + + case DTK_MILLENNIUM: + /* caution: C division may have negative remainder */ + result = int64_to_numeric(tm->tm_year / 1000); + break; + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("interval units \"%s\" not supported", + lowunits))); + result = 0; + } + + } + else + { + elog(ERROR, "could not convert interval to tm"); + result = 0; + } + } + else if (type == RESERV && val == DTK_EPOCH) + { + result = + numeric_add_opt_error( + numeric_div_opt_error(int64_to_numeric(interval->time), + int64_to_numeric(1000000), + NULL), + int64_to_numeric(((int64) DAYS_PER_YEAR * SECS_PER_DAY) * (interval->month / MONTHS_PER_YEAR) + + ((int64) DAYS_PER_MONTH * SECS_PER_DAY) * (interval->month % MONTHS_PER_YEAR) + + ((int64) SECS_PER_DAY) * interval->day), + NULL); + result = DatumGetNumeric(DirectFunctionCall2(numeric_round, + NumericGetDatum(result), + Int32GetDatum(6))); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("interval units \"%s\" not recognized", + lowunits))); + result = 0; + } + + PG_RETURN_NUMERIC(result); +} + + /* timestamp_zone() * Encode timestamp type with specified time zone. * This function is just timestamp2timestamptz() except instead of diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index e6c7b070f6..81e6dcc312 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -2333,9 +2333,15 @@ { oid => '1171', descr => 'extract field from timestamp with time zone', proname => 'date_part', provolatile => 's', prorettype => 'float8', proargtypes => 'text timestamptz', prosrc => 'timestamptz_part' }, +{ oid => '9983', descr => 'extract field from timestamp with time zone', + proname => 'extract', provolatile => 's', prorettype => 'numeric', + proargtypes => 'text timestamptz', prosrc => 'extract_timestamptz' }, { oid => '1172', descr => 'extract field from interval', proname => 'date_part', prorettype => 'float8', proargtypes => 'text interval', prosrc => 'interval_part' }, +{ oid => '9984', descr => 'extract field from interval', + proname => 'extract', prorettype => 'numeric', + proargtypes => 'text interval', prosrc => 'extract_interval' }, { oid => '1174', descr => 'convert date to timestamp with time zone', proname => 'timestamptz', provolatile => 's', prorettype => 'timestamptz', proargtypes => 'date', prosrc => 'date_timestamptz' }, @@ -2483,6 +2489,9 @@ { oid => '1273', descr => 'extract field from time with time zone', proname => 'date_part', prorettype => 'float8', proargtypes => 'text timetz', prosrc => 'timetz_part' }, +{ oid => '9981', descr => 'extract field from time with time zone', + proname => 'extract', prorettype => 'numeric', proargtypes => 'text timetz', + prosrc => 'extract_timetz' }, { oid => '1274', proname => 'int84pl', prorettype => 'int8', proargtypes => 'int8 int4', prosrc => 'int84pl' }, @@ -2828,9 +2837,15 @@ proname => 'date_part', prolang => 'sql', prorettype => 'float8', proargtypes => 'text date', prosrc => 'select pg_catalog.date_part($1, cast($2 as timestamp without time zone))' }, +{ oid => '9979', descr => 'extract field from date', + proname => 'extract', prorettype => 'numeric', proargtypes => 'text date', + prosrc => 'extract_date' }, { oid => '1385', descr => 'extract field from time', proname => 'date_part', prorettype => 'float8', proargtypes => 'text time', prosrc => 'time_part' }, +{ oid => '9980', descr => 'extract field from time', + proname => 'extract', prorettype => 'numeric', proargtypes => 'text time', + prosrc => 'extract_time' }, { oid => '1386', descr => 'date difference from today preserving months and years', proname => 'age', prolang => 'sql', provolatile => 's', @@ -5758,6 +5773,9 @@ { oid => '2021', descr => 'extract field from timestamp', proname => 'date_part', prorettype => 'float8', proargtypes => 'text timestamp', prosrc => 'timestamp_part' }, +{ oid => '9982', descr => 'extract field from timestamp', + proname => 'extract', prorettype => 'numeric', + proargtypes => 'text timestamp', prosrc => 'extract_timestamp' }, { oid => '2024', descr => 'convert date to timestamp', proname => 'timestamp', prorettype => 'timestamp', proargtypes => 'date', prosrc => 'date_timestamp' }, diff --git a/src/test/regress/expected/create_view.out b/src/test/regress/expected/create_view.out index b234d2d4f9..eb11af99a7 100644 --- a/src/test/regress/expected/create_view.out +++ b/src/test/regress/expected/create_view.out @@ -1739,7 +1739,7 @@ select select pg_get_viewdef('tt201v', true); pg_get_viewdef ----------------------------------------------------------------------------------------------- - SELECT date_part('day'::text, now()) AS extr, + + SELECT EXTRACT(day FROM now()) AS extr, + ((now(), '@ 1 day'::interval) OVERLAPS (CURRENT_TIMESTAMP(2), '@ 1 day'::interval)) AS o,+ (('foo'::text) IS NORMALIZED) AS isn, + (('foo'::text) IS NFKC NORMALIZED) AS isnn, + diff --git a/src/test/regress/expected/date.out b/src/test/regress/expected/date.out index 1b921ce215..d7677fc0b5 100644 --- a/src/test/regress/expected/date.out +++ b/src/test/regress/expected/date.out @@ -966,78 +966,78 @@ SELECT f1 as "date", -- epoch -- SELECT EXTRACT(EPOCH FROM DATE '1970-01-01'); -- 0 - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMP '1970-01-01'); -- 0 - date_part ------------ - 0 + extract +---------- + 0.000000 (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '1970-01-01+00'); -- 0 - date_part ------------ - 0 + extract +---------- + 0.000000 (1 row) -- -- century -- SELECT EXTRACT(CENTURY FROM DATE '0101-12-31 BC'); -- -2 - date_part ------------ - -2 + extract +--------- + -2 (1 row) SELECT EXTRACT(CENTURY FROM DATE '0100-12-31 BC'); -- -1 - date_part ------------ - -1 + extract +--------- + -1 (1 row) SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC'); -- -1 - date_part ------------ - -1 + extract +--------- + -1 (1 row) SELECT EXTRACT(CENTURY FROM DATE '0001-01-01'); -- 1 - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD'); -- 1 - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(CENTURY FROM DATE '1900-12-31'); -- 19 - date_part ------------ - 19 + extract +--------- + 19 (1 row) SELECT EXTRACT(CENTURY FROM DATE '1901-01-01'); -- 20 - date_part ------------ - 20 + extract +--------- + 20 (1 row) SELECT EXTRACT(CENTURY FROM DATE '2000-12-31'); -- 20 - date_part ------------ - 20 + extract +--------- + 20 (1 row) SELECT EXTRACT(CENTURY FROM DATE '2001-01-01'); -- 21 - date_part ------------ - 21 + extract +--------- + 21 (1 row) SELECT EXTRACT(CENTURY FROM CURRENT_DATE)>=21 AS True; -- true @@ -1050,91 +1050,91 @@ SELECT EXTRACT(CENTURY FROM CURRENT_DATE)>=21 AS True; -- true -- millennium -- SELECT EXTRACT(MILLENNIUM FROM DATE '0001-12-31 BC'); -- -1 - date_part ------------ - -1 + extract +--------- + -1 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '0001-01-01 AD'); -- 1 - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '1000-12-31'); -- 1 - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '1001-01-01'); -- 2 - date_part ------------ - 2 + extract +--------- + 2 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '2000-12-31'); -- 2 - date_part ------------ - 2 + extract +--------- + 2 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '2001-01-01'); -- 3 - date_part ------------ - 3 + extract +--------- + 3 (1 row) -- next test to be fixed on the turn of the next millennium;-) SELECT EXTRACT(MILLENNIUM FROM CURRENT_DATE); -- 3 - date_part ------------ - 3 + extract +--------- + 3 (1 row) -- -- decade -- SELECT EXTRACT(DECADE FROM DATE '1994-12-25'); -- 199 - date_part ------------ - 199 + extract +--------- + 199 (1 row) SELECT EXTRACT(DECADE FROM DATE '0010-01-01'); -- 1 - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(DECADE FROM DATE '0009-12-31'); -- 0 - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(DECADE FROM DATE '0001-01-01 BC'); -- 0 - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(DECADE FROM DATE '0002-12-31 BC'); -- -1 - date_part ------------ - -1 + extract +--------- + -1 (1 row) SELECT EXTRACT(DECADE FROM DATE '0011-01-01 BC'); -- -1 - date_part ------------ - -1 + extract +--------- + -1 (1 row) SELECT EXTRACT(DECADE FROM DATE '0012-12-31 BC'); -- -2 - date_part ------------ - -2 + extract +--------- + -2 (1 row) -- @@ -1148,135 +1148,112 @@ SELECT EXTRACT(CENTURY FROM NOW())>=21 AS True; -- true (1 row) SELECT EXTRACT(CENTURY FROM TIMESTAMP '1970-03-20 04:30:00.00000'); -- 20 - date_part ------------ - 20 + extract +--------- + 20 (1 row) -- -- all possible fields -- SELECT EXTRACT(MICROSECONDS FROM DATE '2020-08-11'); - date_part ------------ - 0 -(1 row) - +ERROR: date units "microseconds" not supported SELECT EXTRACT(MILLISECONDS FROM DATE '2020-08-11'); - date_part ------------ - 0 -(1 row) - +ERROR: date units "milliseconds" not supported SELECT EXTRACT(SECOND FROM DATE '2020-08-11'); - date_part ------------ - 0 -(1 row) - +ERROR: date units "second" not supported SELECT EXTRACT(MINUTE FROM DATE '2020-08-11'); - date_part ------------ - 0 -(1 row) - +ERROR: date units "minute" not supported SELECT EXTRACT(HOUR FROM DATE '2020-08-11'); - date_part ------------ - 0 -(1 row) - +ERROR: date units "hour" not supported SELECT EXTRACT(DAY FROM DATE '2020-08-11'); - date_part ------------ - 11 + extract +--------- + 11 (1 row) SELECT EXTRACT(MONTH FROM DATE '2020-08-11'); - date_part ------------ - 8 + extract +--------- + 8 (1 row) SELECT EXTRACT(YEAR FROM DATE '2020-08-11'); - date_part ------------ - 2020 + extract +--------- + 2020 (1 row) SELECT EXTRACT(DECADE FROM DATE '2020-08-11'); - date_part ------------ - 202 + extract +--------- + 202 (1 row) SELECT EXTRACT(CENTURY FROM DATE '2020-08-11'); - date_part ------------ - 21 + extract +--------- + 21 (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE '2020-08-11'); - date_part ------------ - 3 + extract +--------- + 3 (1 row) SELECT EXTRACT(ISOYEAR FROM DATE '2020-08-11'); - date_part ------------ - 2020 + extract +--------- + 2020 (1 row) SELECT EXTRACT(QUARTER FROM DATE '2020-08-11'); - date_part ------------ - 3 + extract +--------- + 3 (1 row) SELECT EXTRACT(WEEK FROM DATE '2020-08-11'); - date_part ------------ - 33 + extract +--------- + 33 (1 row) SELECT EXTRACT(DOW FROM DATE '2020-08-11'); - date_part ------------ - 2 + extract +--------- + 2 (1 row) SELECT EXTRACT(ISODOW FROM DATE '2020-08-11'); - date_part ------------ - 2 + extract +--------- + 2 (1 row) SELECT EXTRACT(DOY FROM DATE '2020-08-11'); - date_part ------------ - 224 + extract +--------- + 224 (1 row) SELECT EXTRACT(TIMEZONE FROM DATE '2020-08-11'); -ERROR: timestamp units "timezone" not supported -CONTEXT: SQL function "date_part" statement 1 +ERROR: date units "timezone" not supported SELECT EXTRACT(TIMEZONE_M FROM DATE '2020-08-11'); -ERROR: timestamp units "timezone_m" not supported -CONTEXT: SQL function "date_part" statement 1 +ERROR: date units "timezone_m" not supported SELECT EXTRACT(TIMEZONE_H FROM DATE '2020-08-11'); -ERROR: timestamp units "timezone_h" not supported -CONTEXT: SQL function "date_part" statement 1 +ERROR: date units "timezone_h" not supported SELECT EXTRACT(EPOCH FROM DATE '2020-08-11'); - date_part + extract ------------ 1597104000 (1 row) SELECT EXTRACT(JULIAN FROM DATE '2020-08-11'); - date_part ------------ - 2459073 + extract +--------- + 2459073 (1 row) -- @@ -1372,221 +1349,188 @@ select isfinite('infinity'::date), isfinite('-infinity'::date), isfinite('today' -- -- oscillating fields from non-finite date/timestamptz: -- -SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL - date_part ------------ - +SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL + extract +--------- + (1 row) -SELECT EXTRACT(HOUR FROM DATE '-infinity'); -- NULL - date_part ------------ - +SELECT EXTRACT(DAY FROM DATE '-infinity'); -- NULL + extract +--------- + (1 row) SELECT EXTRACT(HOUR FROM TIMESTAMP 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(HOUR FROM TIMESTAMP '-infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(HOUR FROM TIMESTAMPTZ 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(HOUR FROM TIMESTAMPTZ '-infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) -- all possible fields SELECT EXTRACT(MICROSECONDS FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "microseconds" not supported SELECT EXTRACT(MILLISECONDS FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "milliseconds" not supported SELECT EXTRACT(SECOND FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "second" not supported SELECT EXTRACT(MINUTE FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "minute" not supported SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "hour" not supported SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(MONTH FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(QUARTER FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(WEEK FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(DOW FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(ISODOW FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(DOY FROM DATE 'infinity'); -- NULL - date_part ------------ - + extract +--------- + (1 row) SELECT EXTRACT(TIMEZONE FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "timezone" not supported SELECT EXTRACT(TIMEZONE_M FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "timezone_m" not supported SELECT EXTRACT(TIMEZONE_H FROM DATE 'infinity'); -- NULL - date_part ------------ - -(1 row) - +ERROR: date units "timezone_h" not supported -- -- monotonic fields from non-finite date/timestamptz: -- SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(EPOCH FROM DATE '-infinity'); -- -Infinity - date_part + extract ----------- -Infinity (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMP 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMP '-infinity'); -- -Infinity - date_part + extract ----------- -Infinity (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '-infinity'); -- -Infinity - date_part + extract ----------- -Infinity (1 row) -- all possible fields SELECT EXTRACT(YEAR FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(DECADE FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(CENTURY FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(MILLENNIUM FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(JULIAN FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(ISOYEAR FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity - date_part ------------ - Infinity + extract +---------- + Infinity (1 row) -- -- wrong fields from non-finite date: -- -SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- ERROR: timestamp units "microsec" not recognized -ERROR: timestamp units "microsec" not recognized -CONTEXT: SQL function "date_part" statement 1 +SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- error +ERROR: date units "microsec" not recognized -- test constructors select make_date(2013, 7, 15); make_date diff --git a/src/test/regress/expected/interval.out b/src/test/regress/expected/interval.out index fde4be5271..5f864df194 100644 --- a/src/test/regress/expected/interval.out +++ b/src/test/regress/expected/interval.out @@ -948,18 +948,18 @@ SELECT f1, EXTRACT(MILLENNIUM FROM f1) AS MILLENNIUM, EXTRACT(EPOCH FROM f1) AS EPOCH FROM INTERVAL_TBL; - f1 | microsecond | millisecond | second | minute | hour | day | month | quarter | year | decade | century | millennium | epoch --------------------------------+-------------+-------------+--------+--------+------+-----+-------+---------+------+--------+---------+------------+------------ - @ 1 min | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60 - @ 5 hours | 0 | 0 | 0 | 0 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000 - @ 10 days | 0 | 0 | 0 | 0 | 0 | 10 | 0 | 1 | 0 | 0 | 0 | 0 | 864000 - @ 34 years | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072958400 - @ 3 mons | 0 | 0 | 0 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000 - @ 14 secs ago | -14000000 | -14000 | -14 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -14 - @ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000 | 4 | 3 | 2 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 93784 - @ 6 years | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189345600 - @ 5 mons | 0 | 0 | 0 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000 - @ 5 mons 12 hours | 0 | 0 | 0 | 0 | 12 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200 + f1 | microsecond | millisecond | second | minute | hour | day | month | quarter | year | decade | century | millennium | epoch +-------------------------------+-------------+-------------+------------+--------+------+-----+-------+---------+------+--------+---------+------------+------------------- + @ 1 min | 0 | 0.000 | 0.000000 | 1 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 60.000000 + @ 5 hours | 0 | 0.000 | 0.000000 | 0 | 5 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | 18000.000000 + @ 10 days | 0 | 0.000 | 0.000000 | 0 | 0 | 10 | 0 | 1 | 0 | 0 | 0 | 0 | 864000.000000 + @ 34 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 34 | 3 | 0 | 0 | 1072224000.000000 + @ 3 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 3 | 2 | 0 | 0 | 0 | 0 | 7776000.000000 + @ 14 secs ago | -14000000 | -14000.000 | -14.000000 | 0 | 0 | 0 | 0 | 1 | 0 | 0 | 0 | 0 | -14.000000 + @ 1 day 2 hours 3 mins 4 secs | 4000000 | 4000.000 | 4.000000 | 3 | 2 | 1 | 0 | 1 | 0 | 0 | 0 | 0 | 93784.000000 + @ 6 years | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 0 | 1 | 6 | 0 | 0 | 0 | 189216000.000000 + @ 5 mons | 0 | 0.000 | 0.000000 | 0 | 0 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 12960000.000000 + @ 5 mons 12 hours | 0 | 0.000 | 0.000000 | 0 | 12 | 0 | 5 | 2 | 0 | 0 | 0 | 0 | 13003200.000000 (10 rows) SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error @@ -967,50 +967,50 @@ ERROR: interval units "fortnight" not recognized SELECT EXTRACT(TIMEZONE FROM INTERVAL '2 days'); -- error ERROR: interval units "timezone" not supported SELECT EXTRACT(DECADE FROM INTERVAL '100 y'); - date_part ------------ - 10 + extract +--------- + 10 (1 row) SELECT EXTRACT(DECADE FROM INTERVAL '99 y'); - date_part ------------ - 9 + extract +--------- + 9 (1 row) SELECT EXTRACT(DECADE FROM INTERVAL '-99 y'); - date_part ------------ - -9 + extract +--------- + -9 (1 row) SELECT EXTRACT(DECADE FROM INTERVAL '-100 y'); - date_part ------------ - -10 + extract +--------- + -10 (1 row) SELECT EXTRACT(CENTURY FROM INTERVAL '100 y'); - date_part ------------ - 1 + extract +--------- + 1 (1 row) SELECT EXTRACT(CENTURY FROM INTERVAL '99 y'); - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(CENTURY FROM INTERVAL '-99 y'); - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(CENTURY FROM INTERVAL '-100 y'); - date_part ------------ - -1 + extract +--------- + -1 (1 row) diff --git a/src/test/regress/expected/psql_crosstab.out b/src/test/regress/expected/psql_crosstab.out index eae6fbd051..e09e331016 100644 --- a/src/test/regress/expected/psql_crosstab.out +++ b/src/test/regress/expected/psql_crosstab.out @@ -17,12 +17,12 @@ SELECT v, EXTRACT(year FROM d), count(*) FROM ctv_data GROUP BY 1, 2 ORDER BY 1, 2; - v | date_part | count -----+-----------+------- - v0 | 2014 | 2 - v0 | 2015 | 1 - v1 | 2015 | 3 - v2 | 2015 | 1 + v | extract | count +----+---------+------- + v0 | 2014 | 2 + v0 | 2015 | 1 + v1 | 2015 | 3 + v2 | 2015 | 1 (4 rows) -- basic usage with 3 columns diff --git a/src/test/regress/expected/time.out b/src/test/regress/expected/time.out index 5303cc0c94..f9786e0b4e 100644 --- a/src/test/regress/expected/time.out +++ b/src/test/regress/expected/time.out @@ -131,33 +131,33 @@ HINT: Could not choose a best candidate operator. You might need to add explici -- test EXTRACT -- SELECT EXTRACT(MICROSECOND FROM TIME '2020-05-26 13:30:25.575401'); - date_part ------------ - 25575401 + extract +---------- + 25575401 (1 row) SELECT EXTRACT(MILLISECOND FROM TIME '2020-05-26 13:30:25.575401'); - date_part + extract ----------- 25575.401 (1 row) SELECT EXTRACT(SECOND FROM TIME '2020-05-26 13:30:25.575401'); - date_part + extract ----------- 25.575401 (1 row) SELECT EXTRACT(MINUTE FROM TIME '2020-05-26 13:30:25.575401'); - date_part ------------ - 30 + extract +--------- + 30 (1 row) SELECT EXTRACT(HOUR FROM TIME '2020-05-26 13:30:25.575401'); - date_part ------------ - 13 + extract +--------- + 13 (1 row) SELECT EXTRACT(DAY FROM TIME '2020-05-26 13:30:25.575401'); -- error @@ -167,7 +167,7 @@ ERROR: "time" units "fortnight" not recognized SELECT EXTRACT(TIMEZONE FROM TIME '2020-05-26 13:30:25.575401'); -- error ERROR: "time" units "timezone" not recognized SELECT EXTRACT(EPOCH FROM TIME '2020-05-26 13:30:25.575401'); - date_part + extract -------------- 48625.575401 (1 row) diff --git a/src/test/regress/expected/timetz.out b/src/test/regress/expected/timetz.out index 1ab5ed5105..f4a0a760f7 100644 --- a/src/test/regress/expected/timetz.out +++ b/src/test/regress/expected/timetz.out @@ -148,33 +148,33 @@ HINT: No operator matches the given name and argument types. You might need to -- test EXTRACT -- SELECT EXTRACT(MICROSECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - 25575401 + extract +---------- + 25575401 (1 row) SELECT EXTRACT(MILLISECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part + extract ----------- 25575.401 (1 row) SELECT EXTRACT(SECOND FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part + extract ----------- 25.575401 (1 row) SELECT EXTRACT(MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - 30 + extract +--------- + 30 (1 row) SELECT EXTRACT(HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - 13 + extract +--------- + 13 (1 row) SELECT EXTRACT(DAY FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error @@ -182,25 +182,25 @@ ERROR: "time with time zone" units "day" not recognized SELECT EXTRACT(FORTNIGHT FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); -- error ERROR: "time with time zone" units "fortnight" not recognized SELECT EXTRACT(TIMEZONE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - -14400 + extract +--------- + -14400 (1 row) SELECT EXTRACT(TIMEZONE_HOUR FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - -4 + extract +--------- + -4 (1 row) SELECT EXTRACT(TIMEZONE_MINUTE FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part ------------ - 0 + extract +--------- + 0 (1 row) SELECT EXTRACT(EPOCH FROM TIME WITH TIME ZONE '2020-05-26 13:30:25.575401-04'); - date_part + extract -------------- 63025.575401 (1 row) diff --git a/src/test/regress/sql/date.sql b/src/test/regress/sql/date.sql index 7a734fb1a0..eb0a9d8ddd 100644 --- a/src/test/regress/sql/date.sql +++ b/src/test/regress/sql/date.sql @@ -329,8 +329,8 @@ CREATE TABLE DATE_TBL (f1 date); -- -- oscillating fields from non-finite date/timestamptz: -- -SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL -SELECT EXTRACT(HOUR FROM DATE '-infinity'); -- NULL +SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL +SELECT EXTRACT(DAY FROM DATE '-infinity'); -- NULL SELECT EXTRACT(HOUR FROM TIMESTAMP 'infinity'); -- NULL SELECT EXTRACT(HOUR FROM TIMESTAMP '-infinity'); -- NULL SELECT EXTRACT(HOUR FROM TIMESTAMPTZ 'infinity'); -- NULL @@ -371,7 +371,7 @@ CREATE TABLE DATE_TBL (f1 date); -- -- wrong fields from non-finite date: -- -SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- ERROR: timestamp units "microsec" not recognized +SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- error -- test constructors select make_date(2013, 7, 15); base-commit: a58db3aa10e62e4228aa409ba006014fa07a8ca2 -- 2.29.2