Make extract() do something more reasonable with infinite datetimes.

Historically, extract() just returned zero for any case involving an
infinite timestamp[tz] input; even cases in which the unit name was
invalid.  This is not very sensible.  Instead, return infinity or
-infinity as appropriate when the requested field is one that is
monotonically increasing (e.g, year, epoch), or NULL when it is not
(e.g., day, hour).  Also, throw the expected errors for bad unit names.

BACKWARDS INCOMPATIBLE CHANGE

Vitaly Burovoy, reviewed by Vik Fearing
This commit is contained in:
Tom Lane 2016-01-21 22:26:20 -05:00
parent d9b9289c83
commit 647d87c56a
4 changed files with 405 additions and 12 deletions

View File

@ -7521,6 +7521,17 @@ SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
</variablelist>
</para>
<note>
<para>
When the input value is +/-Infinity, <function>extract</> returns
+/-Infinity for monotonically-increasing fields (<literal>epoch</>,
<literal>julian</>, <literal>year</>, <literal>isoyear</>,
<literal>decade</>, <literal>century</>, and <literal>millennium</>).
For other fields, NULL is returned. <productname>PostgreSQL</>
versions before 9.6 returned zero for all cases of infinite input.
</para>
</note>
<para>
The <function>extract</function> function is primarily intended
for computational processing. For formatting date/time values for

View File

@ -4311,6 +4311,83 @@ date2isoyearday(int year, int mon, int mday)
return date2j(year, mon, mday) - isoweek2j(date2isoyear(year, mon, mday), 1) + 1;
}
/*
* NonFiniteTimestampTzPart
*
* Used by timestamp_part and timestamptz_part when extracting from infinite
* timestamp[tz]. Returns +/-Infinity if that is the appropriate result,
* otherwise returns zero (which should be taken as meaning to return 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 float8
NonFiniteTimestampTzPart(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 0.0;
/* 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 -get_float8_infinity();
else
return get_float8_infinity();
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 0.0; /* keep compiler quiet */
}
}
/* timestamp_part()
* Extract specified field from timestamp.
*/
@ -4327,12 +4404,6 @@ timestamp_part(PG_FUNCTION_ARGS)
struct pg_tm tt,
*tm = &tt;
if (TIMESTAMP_NOT_FINITE(timestamp))
{
result = 0;
PG_RETURN_FLOAT8(result);
}
lowunits = downcase_truncate_identifier(VARDATA_ANY(units),
VARSIZE_ANY_EXHDR(units),
false);
@ -4341,6 +4412,17 @@ timestamp_part(PG_FUNCTION_ARGS)
if (type == UNKNOWN_FIELD)
type = DecodeSpecial(0, lowunits, &val);
if (TIMESTAMP_NOT_FINITE(timestamp))
{
result = NonFiniteTimestampTzPart(type, val, lowunits,
TIMESTAMP_IS_NOBEGIN(timestamp),
false);
if (result)
PG_RETURN_FLOAT8(result);
else
PG_RETURN_NULL();
}
if (type == UNITS)
{
if (timestamp2tm(timestamp, NULL, tm, &fsec, NULL, NULL) != 0)
@ -4538,12 +4620,6 @@ timestamptz_part(PG_FUNCTION_ARGS)
struct pg_tm tt,
*tm = &tt;
if (TIMESTAMP_NOT_FINITE(timestamp))
{
result = 0;
PG_RETURN_FLOAT8(result);
}
lowunits = downcase_truncate_identifier(VARDATA_ANY(units),
VARSIZE_ANY_EXHDR(units),
false);
@ -4552,6 +4628,17 @@ timestamptz_part(PG_FUNCTION_ARGS)
if (type == UNKNOWN_FIELD)
type = DecodeSpecial(0, lowunits, &val);
if (TIMESTAMP_NOT_FINITE(timestamp))
{
result = NonFiniteTimestampTzPart(type, val, lowunits,
TIMESTAMP_IS_NOBEGIN(timestamp),
true);
if (result)
PG_RETURN_FLOAT8(result);
else
PG_RETURN_NULL();
}
if (type == UNITS)
{
if (timestamp2tm(timestamp, &tz, tm, &fsec, NULL, NULL) != 0)

View File

@ -899,6 +899,27 @@ SELECT date 'tomorrow' - date 'yesterday' AS "Two days";
--
-- test extract!
--
-- epoch
--
SELECT EXTRACT(EPOCH FROM DATE '1970-01-01'); -- 0
date_part
-----------
0
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMP '1970-01-01'); -- 0
date_part
-----------
0
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '1970-01-01+00'); -- 0
date_part
-----------
0
(1 row)
--
-- century
--
@ -1184,6 +1205,227 @@ select isfinite('infinity'::date), isfinite('-infinity'::date), isfinite('today'
f | f | t
(1 row)
--
-- oscillating fields from non-finite date/timestamptz:
--
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM DATE '-infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM TIMESTAMP 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM TIMESTAMP '-infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM TIMESTAMPTZ 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM TIMESTAMPTZ '-infinity'); -- NULL
date_part
-----------
(1 row)
-- all possible fields
SELECT EXTRACT(MICROSECONDS FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(MILLISECONDS FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(SECOND FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(MINUTE FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(MONTH FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(QUARTER FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(WEEK FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(DOW FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(ISODOW FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(DOY FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(TIMEZONE FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(TIMEZONE_M FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
SELECT EXTRACT(TIMEZONE_H FROM DATE 'infinity'); -- NULL
date_part
-----------
(1 row)
--
-- monotonic fields from non-finite date/timestamptz:
--
SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM DATE '-infinity'); -- -Infinity
date_part
-----------
-Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMP 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMP '-infinity'); -- -Infinity
date_part
-----------
-Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '-infinity'); -- -Infinity
date_part
-----------
-Infinity
(1 row)
-- all possible fields
SELECT EXTRACT(YEAR FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(DECADE FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(CENTURY FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(MILLENNIUM FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(JULIAN FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(ISOYEAR FROM DATE 'infinity'); -- Infinity
date_part
-----------
Infinity
(1 row)
SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
date_part
-----------
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(UNDEFINED FROM DATE 'infinity'); -- ERROR: timestamp units "undefined" not supported
ERROR: timestamp units "undefined" not supported
CONTEXT: SQL function "date_part" statement 1
-- test constructors
select make_date(2013, 7, 15);
make_date

View File

@ -212,6 +212,12 @@ SELECT date 'tomorrow' - date 'yesterday' AS "Two days";
--
-- test extract!
--
-- epoch
--
SELECT EXTRACT(EPOCH FROM DATE '1970-01-01'); -- 0
SELECT EXTRACT(EPOCH FROM TIMESTAMP '1970-01-01'); -- 0
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '1970-01-01+00'); -- 0
--
-- century
--
SELECT EXTRACT(CENTURY FROM DATE '0101-12-31 BC'); -- -2
@ -276,6 +282,53 @@ select 'infinity'::date, '-infinity'::date;
select 'infinity'::date > 'today'::date as t;
select '-infinity'::date < 'today'::date as t;
select isfinite('infinity'::date), isfinite('-infinity'::date), isfinite('today'::date);
--
-- oscillating fields from non-finite date/timestamptz:
--
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(HOUR 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
SELECT EXTRACT(HOUR FROM TIMESTAMPTZ '-infinity'); -- NULL
-- all possible fields
SELECT EXTRACT(MICROSECONDS FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MILLISECONDS FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(SECOND FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MINUTE FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(HOUR FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DAY FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(MONTH FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(QUARTER FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(WEEK FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DOW FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(ISODOW FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(DOY FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE_M FROM DATE 'infinity'); -- NULL
SELECT EXTRACT(TIMEZONE_H FROM DATE 'infinity'); -- NULL
--
-- monotonic fields from non-finite date/timestamptz:
--
SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(EPOCH FROM DATE '-infinity'); -- -Infinity
SELECT EXTRACT(EPOCH FROM TIMESTAMP 'infinity'); -- Infinity
SELECT EXTRACT(EPOCH FROM TIMESTAMP '-infinity'); -- -Infinity
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ 'infinity'); -- Infinity
SELECT EXTRACT(EPOCH FROM TIMESTAMPTZ '-infinity'); -- -Infinity
-- all possible fields
SELECT EXTRACT(YEAR FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(DECADE FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(CENTURY FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(MILLENNIUM FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(JULIAN FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(ISOYEAR FROM DATE 'infinity'); -- Infinity
SELECT EXTRACT(EPOCH FROM DATE 'infinity'); -- Infinity
--
-- wrong fields from non-finite date:
--
SELECT EXTRACT(MICROSEC FROM DATE 'infinity'); -- ERROR: timestamp units "microsec" not recognized
SELECT EXTRACT(UNDEFINED FROM DATE 'infinity'); -- ERROR: timestamp units "undefined" not supported
-- test constructors
select make_date(2013, 7, 15);