From 519fc1bd9e9d7b408903e44f55f83f6db30742b7 Mon Sep 17 00:00:00 2001 From: Dean Rasheed Date: Tue, 14 Nov 2023 10:58:49 +0000 Subject: [PATCH] Support +/- infinity in the interval data type. This adds support for infinity to the interval data type, using the same input/output representation as the other date/time data types that support infinity. This allows various arithmetic operations on infinite dates, timestamps and intervals. The new values are represented by setting all fields of the interval to INT32/64_MIN for -infinity, and INT32/64_MAX for +infinity. This ensures that they compare as less/greater than all other interval values, without the need for any special-case comparison code. Note that, since those 2 values were formerly accepted as legal finite intervals, pg_upgrade and dump/restore from an old database will turn them from finite to infinite intervals. That seems OK, since those exact values should be extremely rare in practice, and they are outside the documented range supported by the interval type, which gives us a certain amount of leeway. Bump catalog version. Joseph Koshakow, Jian He, and Ashutosh Bapat, reviewed by me. Discussion: https://postgr.es/m/CAAvxfHea4%2BsPybKK7agDYOMo9N-Z3J6ZXf3BOM79pFsFNcRjwA%40mail.gmail.com --- contrib/btree_gin/btree_gin.c | 5 +- doc/src/sgml/datatype.sgml | 4 +- doc/src/sgml/func.sgml | 8 +- src/backend/utils/adt/date.c | 57 +- src/backend/utils/adt/datetime.c | 26 + src/backend/utils/adt/formatting.c | 2 +- src/backend/utils/adt/selfuncs.c | 4 + src/backend/utils/adt/timestamp.c | 1078 +++++++++++++++++---- src/include/catalog/catversion.h | 2 +- src/include/catalog/pg_aggregate.dat | 24 +- src/include/catalog/pg_proc.dat | 28 +- src/include/datatype/timestamp.h | 27 +- src/test/regress/expected/brin_multi.out | 28 + src/test/regress/expected/horology.out | 71 +- src/test/regress/expected/interval.out | 499 +++++++++- src/test/regress/expected/timestamp.out | 62 ++ src/test/regress/expected/timestamptz.out | 62 ++ src/test/regress/expected/window.out | 469 ++++++++- src/test/regress/sql/brin_multi.sql | 19 + src/test/regress/sql/horology.sql | 3 +- src/test/regress/sql/interval.sql | 193 +++- src/test/regress/sql/timestamp.sql | 19 + src/test/regress/sql/timestamptz.sql | 18 + src/test/regress/sql/window.sql | 167 +++- src/tools/pgindent/typedefs.list | 1 + 25 files changed, 2560 insertions(+), 316 deletions(-) diff --git a/contrib/btree_gin/btree_gin.c b/contrib/btree_gin/btree_gin.c index b09bb8df96..5e27906f80 100644 --- a/contrib/btree_gin/btree_gin.c +++ b/contrib/btree_gin/btree_gin.c @@ -306,9 +306,8 @@ leftmostvalue_interval(void) { Interval *v = palloc(sizeof(Interval)); - v->time = PG_INT64_MIN; - v->day = PG_INT32_MIN; - v->month = PG_INT32_MIN; + INTERVAL_NOBEGIN(v); + return IntervalPGetDatum(v); } diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml index 55340b00ad..e4a7b07033 100644 --- a/doc/src/sgml/datatype.sgml +++ b/doc/src/sgml/datatype.sgml @@ -2328,12 +2328,12 @@ TIMESTAMP WITH TIME ZONE '2004-10-19 10:23:54+02' infinity - date, timestamp + date, timestamp, interval later than all other time stamps -infinity - date, timestamp + date, timestamp, interval earlier than all other time stamps diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index d76df6239f..93f068edcf 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -9565,7 +9565,7 @@ SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}'); boolean - Test for finite interval (currently always true) + Test for finite interval (not +/-infinity) isfinite(interval '4 hours') @@ -10462,7 +10462,11 @@ SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); When the input value is +/-Infinity, extract returns +/-Infinity for monotonically-increasing fields (epoch, julian, year, isoyear, - decade, century, and millennium). + decade, century, and millennium + for timestamp inputs; epoch, hour, + day, year, decade, + century, and millennium for + interval inputs). For other fields, NULL is returned. PostgreSQL versions before 9.6 returned zero for all cases of infinite input. diff --git a/src/backend/utils/adt/date.c b/src/backend/utils/adt/date.c index 544e1d32bf..13745a0adc 100644 --- a/src/backend/utils/adt/date.c +++ b/src/backend/utils/adt/date.c @@ -24,6 +24,7 @@ #include "access/xact.h" #include "catalog/pg_type.h" #include "common/hashfn.h" +#include "common/int.h" #include "libpq/pqformat.h" #include "miscadmin.h" #include "nodes/supportnodes.h" @@ -2013,6 +2014,11 @@ interval_time(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(0); TimeADT result; + if (INTERVAL_NOT_FINITE(span)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("cannot convert infinite interval to time"))); + result = span->time % USECS_PER_DAY; if (result < 0) result += USECS_PER_DAY; @@ -2049,6 +2055,11 @@ time_pl_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); TimeADT result; + if (INTERVAL_NOT_FINITE(span)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("cannot add infinite interval to time"))); + result = time + span->time; result -= result / USECS_PER_DAY * USECS_PER_DAY; if (result < INT64CONST(0)) @@ -2067,6 +2078,11 @@ time_mi_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); TimeADT result; + if (INTERVAL_NOT_FINITE(span)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("cannot subtract infinite interval from time"))); + result = time - span->time; result -= result / USECS_PER_DAY * USECS_PER_DAY; if (result < INT64CONST(0)) @@ -2090,7 +2106,8 @@ in_range_time_interval(PG_FUNCTION_ARGS) /* * Like time_pl_interval/time_mi_interval, we disregard the month and day - * fields of the offset. So our test for negative should too. + * fields of the offset. So our test for negative should too. This also + * catches -infinity, so we only need worry about +infinity below. */ if (offset->time < 0) ereport(ERROR, @@ -2100,13 +2117,14 @@ in_range_time_interval(PG_FUNCTION_ARGS) /* * We can't use time_pl_interval/time_mi_interval here, because their * wraparound behavior would give wrong (or at least undesirable) answers. - * Fortunately the equivalent non-wrapping behavior is trivial, especially - * since we don't worry about integer overflow. + * Fortunately the equivalent non-wrapping behavior is trivial, except + * that adding an infinite (or very large) interval might cause integer + * overflow. Subtraction cannot overflow here. */ if (sub) sum = base - offset->time; - else - sum = base + offset->time; + else if (pg_add_s64_overflow(base, offset->time, &sum)) + PG_RETURN_BOOL(less); if (less) PG_RETURN_BOOL(val <= sum); @@ -2581,6 +2599,11 @@ timetz_pl_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); TimeTzADT *result; + if (INTERVAL_NOT_FINITE(span)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("cannot add infinite interval to time"))); + result = (TimeTzADT *) palloc(sizeof(TimeTzADT)); result->time = time->time + span->time; @@ -2603,6 +2626,11 @@ timetz_mi_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); TimeTzADT *result; + if (INTERVAL_NOT_FINITE(span)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("cannot subtract infinite interval from time"))); + result = (TimeTzADT *) palloc(sizeof(TimeTzADT)); result->time = time->time - span->time; @@ -2630,7 +2658,8 @@ in_range_timetz_interval(PG_FUNCTION_ARGS) /* * Like timetz_pl_interval/timetz_mi_interval, we disregard the month and - * day fields of the offset. So our test for negative should too. + * day fields of the offset. So our test for negative should too. This + * also catches -infinity, so we only need worry about +infinity below. */ if (offset->time < 0) ereport(ERROR, @@ -2640,13 +2669,14 @@ in_range_timetz_interval(PG_FUNCTION_ARGS) /* * We can't use timetz_pl_interval/timetz_mi_interval here, because their * wraparound behavior would give wrong (or at least undesirable) answers. - * Fortunately the equivalent non-wrapping behavior is trivial, especially - * since we don't worry about integer overflow. + * Fortunately the equivalent non-wrapping behavior is trivial, except + * that adding an infinite (or very large) interval might cause integer + * overflow. Subtraction cannot overflow here. */ if (sub) sum.time = base->time - offset->time; - else - sum.time = base->time + offset->time; + else if (pg_add_s64_overflow(base->time, offset->time, &sum.time)) + PG_RETURN_BOOL(less); sum.zone = base->zone; if (less) @@ -3096,6 +3126,13 @@ timetz_izone(PG_FUNCTION_ARGS) TimeTzADT *result; int tz; + if (INTERVAL_NOT_FINITE(zone)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("interval time zone \"%s\" must be finite", + DatumGetCString(DirectFunctionCall1(interval_out, + PointerGetDatum(zone)))))); + if (zone->month != 0 || zone->day != 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), diff --git a/src/backend/utils/adt/datetime.c b/src/backend/utils/adt/datetime.c index 267dfd37b2..fca9a2a6e9 100644 --- a/src/backend/utils/adt/datetime.c +++ b/src/backend/utils/adt/datetime.c @@ -3271,6 +3271,9 @@ ClearPgItmIn(struct pg_itm_in *itm_in) * * Allow ISO-style time span, with implicit units on number of days * preceding an hh:mm:ss field. - thomas 1998-04-30 + * + * itm_in remains undefined for infinite interval values for which dtype alone + * suffices. */ int DecodeInterval(char **field, int *ftype, int nf, int range, @@ -3574,6 +3577,8 @@ DecodeInterval(char **field, int *ftype, int nf, int range, if (parsing_unit_val) return DTERR_BAD_FORMAT; type = DecodeUnits(i, field[i], &uval); + if (type == UNKNOWN_FIELD) + type = DecodeSpecial(i, field[i], &uval); if (type == IGNORE_DTF) continue; @@ -3597,6 +3602,27 @@ DecodeInterval(char **field, int *ftype, int nf, int range, type = uval; break; + case RESERV: + tmask = (DTK_DATE_M | DTK_TIME_M); + + /* + * Only reserved words corresponding to infinite + * intervals are accepted. + */ + if (uval != DTK_LATE && uval != DTK_EARLY) + return DTERR_BAD_FORMAT; + + /* + * Infinity cannot be followed by anything else. We + * could allow "ago" to reverse the sign of infinity + * but using signed infinity is more intuitive. + */ + if (i != nf - 1) + return DTERR_BAD_FORMAT; + + *dtype = uval; + break; + default: return DTERR_BAD_FORMAT; } diff --git a/src/backend/utils/adt/formatting.c b/src/backend/utils/adt/formatting.c index 8131091f79..d176723d95 100644 --- a/src/backend/utils/adt/formatting.c +++ b/src/backend/utils/adt/formatting.c @@ -4127,7 +4127,7 @@ interval_to_char(PG_FUNCTION_ARGS) struct pg_itm tt, *itm = &tt; - if (VARSIZE_ANY_EXHDR(fmt) <= 0) + if (VARSIZE_ANY_EXHDR(fmt) <= 0 || INTERVAL_NOT_FINITE(it)) PG_RETURN_NULL(); ZERO_tmtc(&tmtc); diff --git a/src/backend/utils/adt/selfuncs.c b/src/backend/utils/adt/selfuncs.c index c4fcd0076e..4ea5415f20 100644 --- a/src/backend/utils/adt/selfuncs.c +++ b/src/backend/utils/adt/selfuncs.c @@ -4802,6 +4802,10 @@ convert_timevalue_to_scalar(Datum value, Oid typid, bool *failure) * Convert the month part of Interval to days using assumed * average month length of 365.25/12.0 days. Not too * accurate, but plenty good enough for our purposes. + * + * This also works for infinite intervals, which just have all + * fields set to INT_MIN/INT_MAX, and so will produce a result + * smaller/larger than any finite interval. */ return interval->time + interval->day * (double) USECS_PER_DAY + interval->month * ((DAYS_PER_YEAR / (double) MONTHS_PER_YEAR) * USECS_PER_DAY); diff --git a/src/backend/utils/adt/timestamp.c b/src/backend/utils/adt/timestamp.c index 647b97aca6..45abb79e76 100644 --- a/src/backend/utils/adt/timestamp.c +++ b/src/backend/utils/adt/timestamp.c @@ -72,6 +72,21 @@ typedef struct pg_tz *attimezone; } generate_series_timestamptz_fctx; +/* + * The transition datatype for interval aggregates is declared as internal. + * It's a pointer to an IntervalAggState allocated in the aggregate context. + */ +typedef struct IntervalAggState +{ + int64 N; /* count of finite intervals processed */ + Interval sumX; /* sum of finite intervals processed */ + /* These counts are *not* included in N! Use IA_TOTAL_COUNT() as needed */ + int64 pInfcount; /* count of +infinity intervals */ + int64 nInfcount; /* count of -infinity intervals */ +} IntervalAggState; + +#define IA_TOTAL_COUNT(ia) \ + ((ia)->N + (ia)->pInfcount + (ia)->nInfcount) static TimeOffset time2t(const int hour, const int min, const int sec, const fsec_t fsec); static Timestamp dt2local(Timestamp dt, int timezone); @@ -80,6 +95,8 @@ static bool AdjustIntervalForTypmod(Interval *interval, int32 typmod, static TimestampTz timestamp2timestamptz(Timestamp timestamp); static Timestamp timestamptz2timestamp(TimestampTz timestamp); +static void EncodeSpecialInterval(const Interval *interval, char *str); +static void interval_um_internal(const Interval *interval, Interval *result); /* common code for timestamptypmodin and timestamptztypmodin */ static int32 @@ -941,6 +958,14 @@ interval_in(PG_FUNCTION_ARGS) errmsg("interval out of range"))); break; + case DTK_LATE: + INTERVAL_NOEND(result); + break; + + case DTK_EARLY: + INTERVAL_NOBEGIN(result); + break; + default: elog(ERROR, "unexpected dtype %d while parsing interval \"%s\"", dtype, str); @@ -963,8 +988,13 @@ interval_out(PG_FUNCTION_ARGS) *itm = &tt; char buf[MAXDATELEN + 1]; - interval2itm(*span, itm); - EncodeInterval(itm, IntervalStyle, buf); + if (INTERVAL_NOT_FINITE(span)) + EncodeSpecialInterval(span, buf); + else + { + interval2itm(*span, itm); + EncodeInterval(itm, IntervalStyle, buf); + } result = pstrdup(buf); PG_RETURN_CSTRING(result); @@ -1350,6 +1380,10 @@ AdjustIntervalForTypmod(Interval *interval, int32 typmod, INT64CONST(0) }; + /* Typmod has no effect on infinite intervals */ + if (INTERVAL_NOT_FINITE(interval)) + return true; + /* * Unspecified range and precision? Then not necessary to adjust. Setting * typmod to -1 is the convention for all data types. @@ -1536,6 +1570,10 @@ make_interval(PG_FUNCTION_ARGS) pg_add_s64_overflow(result->time, (int64) secs, &result->time)) goto out_of_range; + /* make sure that the result is finite */ + if (INTERVAL_NOT_FINITE(result)) + goto out_of_range; + PG_RETURN_INTERVAL_P(result); out_of_range: @@ -1560,6 +1598,17 @@ EncodeSpecialTimestamp(Timestamp dt, char *str) elog(ERROR, "invalid argument for EncodeSpecialTimestamp"); } +static void +EncodeSpecialInterval(const Interval *interval, char *str) +{ + if (INTERVAL_IS_NOBEGIN(interval)) + strcpy(str, EARLY); + else if (INTERVAL_IS_NOEND(interval)) + strcpy(str, LATE); + else /* shouldn't happen */ + elog(ERROR, "invalid argument for EncodeSpecialInterval"); +} + Datum now(PG_FUNCTION_ARGS) { @@ -2015,6 +2064,9 @@ interval2itm(Interval span, struct pg_itm *itm) /* itm2interval() * Convert a pg_itm structure to an Interval. * Returns 0 if OK, -1 on overflow. + * + * This is for use in computations expected to produce finite results. Any + * inputs that lead to infinite results are treated as overflows. */ int itm2interval(struct pg_itm *itm, Interval *span) @@ -2038,12 +2090,21 @@ itm2interval(struct pg_itm *itm, Interval *span) if (pg_add_s64_overflow(span->time, itm->tm_usec, &span->time)) return -1; + if (INTERVAL_NOT_FINITE(span)) + return -1; return 0; } /* itmin2interval() * Convert a pg_itm_in structure to an Interval. * Returns 0 if OK, -1 on overflow. + * + * Note: if the result is infinite, it is not treated as an overflow. This + * avoids any dump/reload hazards from pre-17 databases that do not support + * infinite intervals, but do allow finite intervals with all fields set to + * INT_MIN/INT_MAX (outside the documented range). Such intervals will be + * silently converted to +/-infinity. This may not be ideal, but seems + * preferable to failure, and ought to be pretty unlikely in practice. */ int itmin2interval(struct pg_itm_in *itm_in, Interval *span) @@ -2088,7 +2149,9 @@ timestamp_finite(PG_FUNCTION_ARGS) Datum interval_finite(PG_FUNCTION_ARGS) { - PG_RETURN_BOOL(true); + Interval *interval = PG_GETARG_INTERVAL_P(0); + + PG_RETURN_BOOL(!INTERVAL_NOT_FINITE(interval)); } @@ -2442,6 +2505,15 @@ interval_cmp_internal(const Interval *interval1, const Interval *interval2) return int128_compare(span1, span2); } +static int +interval_sign(const Interval *interval) +{ + INT128 span = interval_cmp_value(interval); + INT128 zero = int64_to_int128(0); + + return int128_compare(span, zero); +} + Datum interval_eq(PG_FUNCTION_ARGS) { @@ -2714,10 +2786,39 @@ timestamp_mi(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the interval type has nothing equivalent to NaN. + */ if (TIMESTAMP_NOT_FINITE(dt1) || TIMESTAMP_NOT_FINITE(dt2)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("cannot subtract infinite timestamps"))); + { + if (TIMESTAMP_IS_NOBEGIN(dt1)) + { + if (TIMESTAMP_IS_NOBEGIN(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOBEGIN(result); + } + else if (TIMESTAMP_IS_NOEND(dt1)) + { + if (TIMESTAMP_IS_NOEND(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOEND(result); + } + else if (TIMESTAMP_IS_NOBEGIN(dt2)) + INTERVAL_NOEND(result); + else /* TIMESTAMP_IS_NOEND(dt2) */ + INTERVAL_NOBEGIN(result); + + PG_RETURN_INTERVAL_P(result); + } if (unlikely(pg_sub_s64_overflow(dt1, dt2, &result->time))) ereport(ERROR, @@ -2783,6 +2884,10 @@ interval_justify_interval(PG_FUNCTION_ARGS) result->day = span->day; result->time = span->time; + /* do nothing for infinite intervals */ + if (INTERVAL_NOT_FINITE(result)) + PG_RETURN_INTERVAL_P(result); + /* pre-justify days if it might prevent overflow */ if ((result->day > 0 && result->time > 0) || (result->day < 0 && result->time < 0)) @@ -2858,6 +2963,10 @@ interval_justify_hours(PG_FUNCTION_ARGS) result->day = span->day; result->time = span->time; + /* do nothing for infinite intervals */ + if (INTERVAL_NOT_FINITE(result)) + PG_RETURN_INTERVAL_P(result); + TMODULO(result->time, wholeday, USECS_PER_DAY); if (pg_add_s32_overflow(result->day, wholeday, &result->day)) ereport(ERROR, @@ -2896,6 +3005,10 @@ interval_justify_days(PG_FUNCTION_ARGS) result->day = span->day; result->time = span->time; + /* do nothing for infinite intervals */ + if (INTERVAL_NOT_FINITE(result)) + PG_RETURN_INTERVAL_P(result); + wholemonth = result->day / DAYS_PER_MONTH; result->day -= wholemonth * DAYS_PER_MONTH; if (pg_add_s32_overflow(result->month, wholemonth, &result->month)) @@ -2934,7 +3047,31 @@ timestamp_pl_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); Timestamp result; - if (TIMESTAMP_NOT_FINITE(timestamp)) + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the timestamp type has nothing equivalent to NaN. + */ + if (INTERVAL_IS_NOBEGIN(span)) + { + if (TIMESTAMP_IS_NOEND(timestamp)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + else + TIMESTAMP_NOBEGIN(result); + } + else if (INTERVAL_IS_NOEND(span)) + { + if (TIMESTAMP_IS_NOBEGIN(timestamp)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + else + TIMESTAMP_NOEND(result); + } + else if (TIMESTAMP_NOT_FINITE(timestamp)) result = timestamp; else { @@ -3013,9 +3150,7 @@ timestamp_mi_interval(PG_FUNCTION_ARGS) Interval *span = PG_GETARG_INTERVAL_P(1); Interval tspan; - tspan.month = -span->month; - tspan.day = -span->day; - tspan.time = -span->time; + interval_um_internal(span, &tspan); return DirectFunctionCall2(timestamp_pl_interval, TimestampGetDatum(timestamp), @@ -3042,7 +3177,31 @@ timestamptz_pl_interval_internal(TimestampTz timestamp, TimestampTz result; int tz; - if (TIMESTAMP_NOT_FINITE(timestamp)) + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the timestamptz type has nothing equivalent to NaN. + */ + if (INTERVAL_IS_NOBEGIN(span)) + { + if (TIMESTAMP_IS_NOEND(timestamp)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + else + TIMESTAMP_NOBEGIN(result); + } + else if (INTERVAL_IS_NOEND(span)) + { + if (TIMESTAMP_IS_NOBEGIN(timestamp)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamp out of range"))); + else + TIMESTAMP_NOEND(result); + } + else if (TIMESTAMP_NOT_FINITE(timestamp)) result = timestamp; else { @@ -3132,9 +3291,7 @@ timestamptz_mi_interval_internal(TimestampTz timestamp, { Interval tspan; - tspan.month = -span->month; - tspan.day = -span->day; - tspan.time = -span->time; + interval_um_internal(span, &tspan); return timestamptz_pl_interval_internal(timestamp, &tspan, attimezone); } @@ -3185,6 +3342,29 @@ timestamptz_mi_interval_at_zone(PG_FUNCTION_ARGS) PG_RETURN_TIMESTAMP(timestamptz_mi_interval_internal(timestamp, span, attimezone)); } +/* interval_um_internal() + * Negate an interval. + */ +static void +interval_um_internal(const Interval *interval, Interval *result) +{ + if (INTERVAL_IS_NOBEGIN(interval)) + INTERVAL_NOEND(result); + else if (INTERVAL_IS_NOEND(interval)) + INTERVAL_NOBEGIN(result); + else + { + /* Negate each field, guarding against overflow */ + if (pg_sub_s64_overflow(INT64CONST(0), interval->time, &result->time) || + pg_sub_s32_overflow(0, interval->day, &result->day) || + pg_sub_s32_overflow(0, interval->month, &result->month) || + INTERVAL_NOT_FINITE(result)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + } +} + Datum interval_um(PG_FUNCTION_ARGS) { @@ -3192,23 +3372,7 @@ interval_um(PG_FUNCTION_ARGS) Interval *result; result = (Interval *) palloc(sizeof(Interval)); - - result->time = -interval->time; - /* overflow check copied from int4um */ - if (interval->time != 0 && SAMESIGN(result->time, interval->time)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - result->day = -interval->day; - if (interval->day != 0 && SAMESIGN(result->day, interval->day)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - result->month = -interval->month; - if (interval->month != 0 && SAMESIGN(result->month, interval->month)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); + interval_um_internal(interval, result); PG_RETURN_INTERVAL_P(result); } @@ -3243,6 +3407,21 @@ interval_larger(PG_FUNCTION_ARGS) PG_RETURN_INTERVAL_P(result); } +static void +finite_interval_pl(const Interval *span1, const Interval *span2, Interval *result) +{ + Assert(!INTERVAL_NOT_FINITE(span1)); + Assert(!INTERVAL_NOT_FINITE(span2)); + + if (pg_add_s32_overflow(span1->month, span2->month, &result->month) || + pg_add_s32_overflow(span1->day, span2->day, &result->day) || + pg_add_s64_overflow(span1->time, span2->time, &result->time) || + INTERVAL_NOT_FINITE(result)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); +} + Datum interval_pl(PG_FUNCTION_ARGS) { @@ -3252,31 +3431,53 @@ interval_pl(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); - result->month = span1->month + span2->month; - /* overflow check copied from int4pl */ - if (SAMESIGN(span1->month, span2->month) && - !SAMESIGN(result->month, span1->month)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - - result->day = span1->day + span2->day; - if (SAMESIGN(span1->day, span2->day) && - !SAMESIGN(result->day, span1->day)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - - result->time = span1->time + span2->time; - if (SAMESIGN(span1->time, span2->time) && - !SAMESIGN(result->time, span1->time)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the interval type has nothing equivalent to NaN. + */ + if (INTERVAL_IS_NOBEGIN(span1)) + { + if (INTERVAL_IS_NOEND(span2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOBEGIN(result); + } + else if (INTERVAL_IS_NOEND(span1)) + { + if (INTERVAL_IS_NOBEGIN(span2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOEND(result); + } + else if (INTERVAL_NOT_FINITE(span2)) + memcpy(result, span2, sizeof(Interval)); + else + finite_interval_pl(span1, span2, result); PG_RETURN_INTERVAL_P(result); } +static void +finite_interval_mi(const Interval *span1, const Interval *span2, Interval *result) +{ + Assert(!INTERVAL_NOT_FINITE(span1)); + Assert(!INTERVAL_NOT_FINITE(span2)); + + if (pg_sub_s32_overflow(span1->month, span2->month, &result->month) || + pg_sub_s32_overflow(span1->day, span2->day, &result->day) || + pg_sub_s64_overflow(span1->time, span2->time, &result->time) || + INTERVAL_NOT_FINITE(result)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); +} + Datum interval_mi(PG_FUNCTION_ARGS) { @@ -3286,27 +3487,36 @@ interval_mi(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); - result->month = span1->month - span2->month; - /* overflow check copied from int4mi */ - if (!SAMESIGN(span1->month, span2->month) && - !SAMESIGN(result->month, span1->month)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - - result->day = span1->day - span2->day; - if (!SAMESIGN(span1->day, span2->day) && - !SAMESIGN(result->day, span1->day)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); - - result->time = span1->time - span2->time; - if (!SAMESIGN(span1->time, span2->time) && - !SAMESIGN(result->time, span1->time)) - ereport(ERROR, - (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), - errmsg("interval out of range"))); + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the interval type has nothing equivalent to NaN. + */ + if (INTERVAL_IS_NOBEGIN(span1)) + { + if (INTERVAL_IS_NOBEGIN(span2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOBEGIN(result); + } + else if (INTERVAL_IS_NOEND(span1)) + { + if (INTERVAL_IS_NOEND(span2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOEND(result); + } + else if (INTERVAL_IS_NOBEGIN(span2)) + INTERVAL_NOEND(result); + else if (INTERVAL_IS_NOEND(span2)) + INTERVAL_NOBEGIN(result); + else + finite_interval_mi(span1, span2, result); PG_RETURN_INTERVAL_P(result); } @@ -3331,6 +3541,46 @@ interval_mul(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); + /* + * Handle NaN and infinities. + * + * We treat "0 * infinity" and "infinity * 0" as errors, since the + * interval type has nothing equivalent to NaN. + */ + if (isnan(factor)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + + if (INTERVAL_NOT_FINITE(span)) + { + if (factor == 0.0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else if (factor < 0.0) + interval_um_internal(span, result); + else + memcpy(result, span, sizeof(Interval)); + + PG_RETURN_INTERVAL_P(result); + } + if (isinf(factor)) + { + int isign = interval_sign(span); + + if (isign == 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else if (factor * isign < 0) + INTERVAL_NOBEGIN(result); + else + INTERVAL_NOEND(result); + + PG_RETURN_INTERVAL_P(result); + } + result_double = span->month * factor; if (isnan(result_double) || result_double > INT_MAX || result_double < INT_MIN) @@ -3391,6 +3641,11 @@ interval_mul(PG_FUNCTION_ARGS) errmsg("interval out of range"))); result->time = (int64) result_double; + if (INTERVAL_NOT_FINITE(result)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + PG_RETURN_INTERVAL_P(result); } @@ -3422,6 +3677,33 @@ interval_div(PG_FUNCTION_ARGS) (errcode(ERRCODE_DIVISION_BY_ZERO), errmsg("division by zero"))); + /* + * Handle NaN and infinities. + * + * We treat "infinity / infinity" as an error, since the interval type has + * nothing equivalent to NaN. Otherwise, dividing by infinity is handled + * by the regular division code, causing all fields to be set to zero. + */ + if (isnan(factor)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + + if (INTERVAL_NOT_FINITE(span)) + { + if (isinf(factor)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + + if (factor < 0.0) + interval_um_internal(span, result); + else + memcpy(result, span, sizeof(Interval)); + + PG_RETURN_INTERVAL_P(result); + } + result->month = (int32) (span->month / factor); result->day = (int32) (span->day / factor); @@ -3443,6 +3725,11 @@ interval_div(PG_FUNCTION_ARGS) result->day += (int32) month_remainder_days; result->time = rint(span->time / factor + sec_remainder * USECS_PER_SEC); + if (INTERVAL_NOT_FINITE(result)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + PG_RETURN_INTERVAL_P(result); } @@ -3466,11 +3753,21 @@ in_range_timestamptz_interval(PG_FUNCTION_ARGS) bool less = PG_GETARG_BOOL(4); TimestampTz sum; - if (int128_compare(interval_cmp_value(offset), int64_to_int128(0)) < 0) + if (interval_sign(offset) < 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PRECEDING_OR_FOLLOWING_SIZE), errmsg("invalid preceding or following size in window function"))); + /* + * Deal with cases where both base and offset are infinite, and computing + * base +/- offset would cause an error. As for float and numeric types, + * we assume that all values infinitely precede +infinity and infinitely + * follow -infinity. See in_range_float8_float8() for reasoning. + */ + if (INTERVAL_IS_NOEND(offset) && + (sub ? TIMESTAMP_IS_NOEND(base) : TIMESTAMP_IS_NOBEGIN(base))) + PG_RETURN_BOOL(true); + /* We don't currently bother to avoid overflow hazards here */ if (sub) sum = timestamptz_mi_interval_internal(base, offset, NULL); @@ -3493,11 +3790,21 @@ in_range_timestamp_interval(PG_FUNCTION_ARGS) bool less = PG_GETARG_BOOL(4); Timestamp sum; - if (int128_compare(interval_cmp_value(offset), int64_to_int128(0)) < 0) + if (interval_sign(offset) < 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PRECEDING_OR_FOLLOWING_SIZE), errmsg("invalid preceding or following size in window function"))); + /* + * Deal with cases where both base and offset are infinite, and computing + * base +/- offset would cause an error. As for float and numeric types, + * we assume that all values infinitely precede +infinity and infinitely + * follow -infinity. See in_range_float8_float8() for reasoning. + */ + if (INTERVAL_IS_NOEND(offset) && + (sub ? TIMESTAMP_IS_NOEND(base) : TIMESTAMP_IS_NOBEGIN(base))) + PG_RETURN_BOOL(true); + /* We don't currently bother to avoid overflow hazards here */ if (sub) sum = DatumGetTimestamp(DirectFunctionCall2(timestamp_mi_interval, @@ -3524,11 +3831,21 @@ in_range_interval_interval(PG_FUNCTION_ARGS) bool less = PG_GETARG_BOOL(4); Interval *sum; - if (int128_compare(interval_cmp_value(offset), int64_to_int128(0)) < 0) + if (interval_sign(offset) < 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PRECEDING_OR_FOLLOWING_SIZE), errmsg("invalid preceding or following size in window function"))); + /* + * Deal with cases where both base and offset are infinite, and computing + * base +/- offset would cause an error. As for float and numeric types, + * we assume that all values infinitely precede +infinity and infinitely + * follow -infinity. See in_range_float8_float8() for reasoning. + */ + if (INTERVAL_IS_NOEND(offset) && + (sub ? INTERVAL_IS_NOEND(base) : INTERVAL_IS_NOBEGIN(base))) + PG_RETURN_BOOL(true); + /* We don't currently bother to avoid overflow hazards here */ if (sub) sum = DatumGetIntervalP(DirectFunctionCall2(interval_mi, @@ -3547,161 +3864,327 @@ in_range_interval_interval(PG_FUNCTION_ARGS) /* - * interval_accum, interval_accum_inv, and interval_avg implement the - * AVG(interval) aggregate. + * Prepare state data for an interval aggregate function, that needs to compute + * sum and count, in the aggregate's memory context. * - * The transition datatype for this aggregate is a 2-element array of - * intervals, where the first is the running sum and the second contains - * the number of values so far in its 'time' field. This is a bit ugly - * but it beats inventing a specialized datatype for the purpose. + * The function is used when the state data needs to be allocated in aggregate's + * context. When the state data needs to be allocated in the current memory + * context, we use palloc0 directly e.g. interval_avg_deserialize(). */ - -Datum -interval_accum(PG_FUNCTION_ARGS) +static IntervalAggState * +makeIntervalAggState(FunctionCallInfo fcinfo) { - ArrayType *transarray = PG_GETARG_ARRAYTYPE_P(0); - Interval *newval = PG_GETARG_INTERVAL_P(1); - Datum *transdatums; - int ndatums; - Interval sumX, - N; - Interval *newsum; - ArrayType *result; + IntervalAggState *state; + MemoryContext agg_context; + MemoryContext old_context; - deconstruct_array(transarray, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE, - &transdatums, NULL, &ndatums); - if (ndatums != 2) - elog(ERROR, "expected 2-element interval array"); + if (!AggCheckCallContext(fcinfo, &agg_context)) + elog(ERROR, "aggregate function called in non-aggregate context"); - sumX = *(DatumGetIntervalP(transdatums[0])); - N = *(DatumGetIntervalP(transdatums[1])); + old_context = MemoryContextSwitchTo(agg_context); - newsum = DatumGetIntervalP(DirectFunctionCall2(interval_pl, - IntervalPGetDatum(&sumX), - IntervalPGetDatum(newval))); - N.time += 1; + state = (IntervalAggState *) palloc0(sizeof(IntervalAggState)); - transdatums[0] = IntervalPGetDatum(newsum); - transdatums[1] = IntervalPGetDatum(&N); + MemoryContextSwitchTo(old_context); - result = construct_array(transdatums, 2, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE); - - PG_RETURN_ARRAYTYPE_P(result); + return state; } -Datum -interval_combine(PG_FUNCTION_ARGS) +/* + * Accumulate a new input value for interval aggregate functions. + */ +static void +do_interval_accum(IntervalAggState *state, Interval *newval) { - ArrayType *transarray1 = PG_GETARG_ARRAYTYPE_P(0); - ArrayType *transarray2 = PG_GETARG_ARRAYTYPE_P(1); - Datum *transdatums1; - Datum *transdatums2; - int ndatums1; - int ndatums2; - Interval sum1, - N1; - Interval sum2, - N2; + /* Infinite inputs are counted separately, and do not affect "N" */ + if (INTERVAL_IS_NOBEGIN(newval)) + { + state->nInfcount++; + return; + } - Interval *newsum; - ArrayType *result; + if (INTERVAL_IS_NOEND(newval)) + { + state->pInfcount++; + return; + } - deconstruct_array(transarray1, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE, - &transdatums1, NULL, &ndatums1); - if (ndatums1 != 2) - elog(ERROR, "expected 2-element interval array"); - - sum1 = *(DatumGetIntervalP(transdatums1[0])); - N1 = *(DatumGetIntervalP(transdatums1[1])); - - deconstruct_array(transarray2, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE, - &transdatums2, NULL, &ndatums2); - if (ndatums2 != 2) - elog(ERROR, "expected 2-element interval array"); - - sum2 = *(DatumGetIntervalP(transdatums2[0])); - N2 = *(DatumGetIntervalP(transdatums2[1])); - - newsum = DatumGetIntervalP(DirectFunctionCall2(interval_pl, - IntervalPGetDatum(&sum1), - IntervalPGetDatum(&sum2))); - N1.time += N2.time; - - transdatums1[0] = IntervalPGetDatum(newsum); - transdatums1[1] = IntervalPGetDatum(&N1); - - result = construct_array(transdatums1, 2, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE); - - PG_RETURN_ARRAYTYPE_P(result); + finite_interval_pl(&state->sumX, newval, &state->sumX); + state->N++; } -Datum -interval_accum_inv(PG_FUNCTION_ARGS) +/* + * Remove the given interval value from the aggregated state. + */ +static void +do_interval_discard(IntervalAggState *state, Interval *newval) { - ArrayType *transarray = PG_GETARG_ARRAYTYPE_P(0); - Interval *newval = PG_GETARG_INTERVAL_P(1); - Datum *transdatums; - int ndatums; - Interval sumX, - N; - Interval *newsum; - ArrayType *result; + /* Infinite inputs are counted separately, and do not affect "N" */ + if (INTERVAL_IS_NOBEGIN(newval)) + { + state->nInfcount--; + return; + } - deconstruct_array(transarray, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE, - &transdatums, NULL, &ndatums); - if (ndatums != 2) - elog(ERROR, "expected 2-element interval array"); + if (INTERVAL_IS_NOEND(newval)) + { + state->pInfcount--; + return; + } - sumX = *(DatumGetIntervalP(transdatums[0])); - N = *(DatumGetIntervalP(transdatums[1])); - - newsum = DatumGetIntervalP(DirectFunctionCall2(interval_mi, - IntervalPGetDatum(&sumX), - IntervalPGetDatum(newval))); - N.time -= 1; - - transdatums[0] = IntervalPGetDatum(newsum); - transdatums[1] = IntervalPGetDatum(&N); - - result = construct_array(transdatums, 2, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE); - - PG_RETURN_ARRAYTYPE_P(result); + /* Handle the to-be-discarded finite value. */ + state->N--; + if (state->N > 0) + finite_interval_mi(&state->sumX, newval, &state->sumX); + else + { + /* All values discarded, reset the state */ + Assert(state->N == 0); + memset(&state->sumX, 0, sizeof(state->sumX)); + } } +/* + * Transition function for sum() and avg() interval aggregates. + */ +Datum +interval_avg_accum(PG_FUNCTION_ARGS) +{ + IntervalAggState *state; + + state = PG_ARGISNULL(0) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(0); + + /* Create the state data on the first call */ + if (state == NULL) + state = makeIntervalAggState(fcinfo); + + if (!PG_ARGISNULL(1)) + do_interval_accum(state, PG_GETARG_INTERVAL_P(1)); + + PG_RETURN_POINTER(state); +} + +/* + * Combine function for sum() and avg() interval aggregates. + * + * Combine the given internal aggregate states and place the combination in + * the first argument. + */ +Datum +interval_avg_combine(PG_FUNCTION_ARGS) +{ + IntervalAggState *state1; + IntervalAggState *state2; + + state1 = PG_ARGISNULL(0) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(0); + state2 = PG_ARGISNULL(1) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(1); + + if (state2 == NULL) + PG_RETURN_POINTER(state1); + + if (state1 == NULL) + { + /* manually copy all fields from state2 to state1 */ + state1 = makeIntervalAggState(fcinfo); + + state1->N = state2->N; + state1->pInfcount = state2->pInfcount; + state1->nInfcount = state2->nInfcount; + + state1->sumX.day = state2->sumX.day; + state1->sumX.month = state2->sumX.month; + state1->sumX.time = state2->sumX.time; + + PG_RETURN_POINTER(state1); + } + + state1->N += state2->N; + state1->pInfcount += state2->pInfcount; + state1->nInfcount += state2->nInfcount; + + /* Accumulate finite interval values, if any. */ + if (state2->N > 0) + finite_interval_pl(&state1->sumX, &state2->sumX, &state1->sumX); + + PG_RETURN_POINTER(state1); +} + +/* + * interval_avg_serialize + * Serialize IntervalAggState for interval aggregates. + */ +Datum +interval_avg_serialize(PG_FUNCTION_ARGS) +{ + IntervalAggState *state; + StringInfoData buf; + bytea *result; + + /* Ensure we disallow calling when not in aggregate context */ + if (!AggCheckCallContext(fcinfo, NULL)) + elog(ERROR, "aggregate function called in non-aggregate context"); + + state = (IntervalAggState *) PG_GETARG_POINTER(0); + + pq_begintypsend(&buf); + + /* N */ + pq_sendint64(&buf, state->N); + + /* sumX */ + pq_sendint64(&buf, state->sumX.time); + pq_sendint32(&buf, state->sumX.day); + pq_sendint32(&buf, state->sumX.month); + + /* pInfcount */ + pq_sendint64(&buf, state->pInfcount); + + /* nInfcount */ + pq_sendint64(&buf, state->nInfcount); + + result = pq_endtypsend(&buf); + + PG_RETURN_BYTEA_P(result); +} + +/* + * interval_avg_deserialize + * Deserialize bytea into IntervalAggState for interval aggregates. + */ +Datum +interval_avg_deserialize(PG_FUNCTION_ARGS) +{ + bytea *sstate; + IntervalAggState *result; + StringInfoData buf; + + if (!AggCheckCallContext(fcinfo, NULL)) + elog(ERROR, "aggregate function called in non-aggregate context"); + + sstate = PG_GETARG_BYTEA_PP(0); + + /* + * Initialize a StringInfo so that we can "receive" it using the standard + * recv-function infrastructure. + */ + initReadOnlyStringInfo(&buf, VARDATA_ANY(sstate), + VARSIZE_ANY_EXHDR(sstate)); + + result = (IntervalAggState *) palloc0(sizeof(IntervalAggState)); + + /* N */ + result->N = pq_getmsgint64(&buf); + + /* sumX */ + result->sumX.time = pq_getmsgint64(&buf); + result->sumX.day = pq_getmsgint(&buf, 4); + result->sumX.month = pq_getmsgint(&buf, 4); + + /* pInfcount */ + result->pInfcount = pq_getmsgint64(&buf); + + /* nInfcount */ + result->nInfcount = pq_getmsgint64(&buf); + + pq_getmsgend(&buf); + + PG_RETURN_POINTER(result); +} + +/* + * Inverse transition function for sum() and avg() interval aggregates. + */ +Datum +interval_avg_accum_inv(PG_FUNCTION_ARGS) +{ + IntervalAggState *state; + + state = PG_ARGISNULL(0) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(0); + + /* Should not get here with no state */ + if (state == NULL) + elog(ERROR, "interval_avg_accum_inv called with NULL state"); + + if (!PG_ARGISNULL(1)) + do_interval_discard(state, PG_GETARG_INTERVAL_P(1)); + + PG_RETURN_POINTER(state); +} + +/* avg(interval) aggregate final function */ Datum interval_avg(PG_FUNCTION_ARGS) { - ArrayType *transarray = PG_GETARG_ARRAYTYPE_P(0); - Datum *transdatums; - int ndatums; - Interval sumX, - N; + IntervalAggState *state; - deconstruct_array(transarray, - INTERVALOID, sizeof(Interval), false, TYPALIGN_DOUBLE, - &transdatums, NULL, &ndatums); - if (ndatums != 2) - elog(ERROR, "expected 2-element interval array"); + state = PG_ARGISNULL(0) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(0); - sumX = *(DatumGetIntervalP(transdatums[0])); - N = *(DatumGetIntervalP(transdatums[1])); - - /* SQL defines AVG of no values to be NULL */ - if (N.time == 0) + /* If there were no non-null inputs, return NULL */ + if (state == NULL || IA_TOTAL_COUNT(state) == 0) PG_RETURN_NULL(); + /* + * Aggregating infinities that all have the same sign produces infinity + * with that sign. Aggregating infinities with different signs results in + * an error. + */ + if (state->pInfcount > 0 || state->nInfcount > 0) + { + Interval *result; + + if (state->pInfcount > 0 && state->nInfcount > 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range."))); + + result = (Interval *) palloc(sizeof(Interval)); + if (state->pInfcount > 0) + INTERVAL_NOEND(result); + else + INTERVAL_NOBEGIN(result); + + PG_RETURN_INTERVAL_P(result); + } + return DirectFunctionCall2(interval_div, - IntervalPGetDatum(&sumX), - Float8GetDatum((double) N.time)); + IntervalPGetDatum(&state->sumX), + Float8GetDatum((double) state->N)); } +/* sum(interval) aggregate final function */ +Datum +interval_sum(PG_FUNCTION_ARGS) +{ + IntervalAggState *state; + Interval *result; + + state = PG_ARGISNULL(0) ? NULL : (IntervalAggState *) PG_GETARG_POINTER(0); + + /* If there were no non-null inputs, return NULL */ + if (state == NULL || IA_TOTAL_COUNT(state) == 0) + PG_RETURN_NULL(); + + /* + * Aggregating infinities that all have the same sign produces infinity + * with that sign. Aggregating infinities with different signs results in + * an error. + */ + if (state->pInfcount > 0 && state->nInfcount > 0) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range."))); + + result = (Interval *) palloc(sizeof(Interval)); + + if (state->pInfcount > 0) + INTERVAL_NOEND(result); + else if (state->nInfcount > 0) + INTERVAL_NOBEGIN(result); + else + memcpy(result, &state->sumX, sizeof(Interval)); + + PG_RETURN_INTERVAL_P(result); +} /* timestamp_age() * Calculate time difference while retaining year/month fields. @@ -3726,8 +4209,36 @@ timestamp_age(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); - if (timestamp2tm(dt1, NULL, tm1, &fsec1, NULL, NULL) == 0 && - timestamp2tm(dt2, NULL, tm2, &fsec2, NULL, NULL) == 0) + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the interval type has nothing equivalent to NaN. + */ + if (TIMESTAMP_IS_NOBEGIN(dt1)) + { + if (TIMESTAMP_IS_NOBEGIN(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOBEGIN(result); + } + else if (TIMESTAMP_IS_NOEND(dt1)) + { + if (TIMESTAMP_IS_NOEND(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOEND(result); + } + else if (TIMESTAMP_IS_NOBEGIN(dt2)) + INTERVAL_NOEND(result); + else if (TIMESTAMP_IS_NOEND(dt2)) + INTERVAL_NOBEGIN(result); + else if (timestamp2tm(dt1, NULL, tm1, &fsec1, NULL, NULL) == 0 && + timestamp2tm(dt2, NULL, tm2, &fsec2, NULL, NULL) == 0) { /* form the symbolic difference */ tm->tm_usec = fsec1 - fsec2; @@ -3846,8 +4357,36 @@ timestamptz_age(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); - if (timestamp2tm(dt1, &tz1, tm1, &fsec1, NULL, NULL) == 0 && - timestamp2tm(dt2, &tz2, tm2, &fsec2, NULL, NULL) == 0) + /* + * Handle infinities. + * + * We treat anything that amounts to "infinity - infinity" as an error, + * since the interval type has nothing equivalent to NaN. + */ + if (TIMESTAMP_IS_NOBEGIN(dt1)) + { + if (TIMESTAMP_IS_NOBEGIN(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOBEGIN(result); + } + else if (TIMESTAMP_IS_NOEND(dt1)) + { + if (TIMESTAMP_IS_NOEND(dt2)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("interval out of range"))); + else + INTERVAL_NOEND(result); + } + else if (TIMESTAMP_IS_NOBEGIN(dt2)) + INTERVAL_NOEND(result); + else if (TIMESTAMP_IS_NOEND(dt2)) + INTERVAL_NOBEGIN(result); + else if (timestamp2tm(dt1, &tz1, tm1, &fsec1, NULL, NULL) == 0 && + timestamp2tm(dt2, &tz2, tm2, &fsec2, NULL, NULL) == 0) { /* form the symbolic difference */ tm->tm_usec = fsec1 - fsec2; @@ -3972,6 +4511,11 @@ timestamp_bin(PG_FUNCTION_ARGS) (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), errmsg("origin out of range"))); + if (INTERVAL_NOT_FINITE(stride)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamps cannot be binned into infinite intervals"))); + if (stride->month != 0) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), @@ -4155,6 +4699,11 @@ timestamptz_bin(PG_FUNCTION_ARGS) (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), errmsg("origin out of range"))); + if (INTERVAL_NOT_FINITE(stride)) + ereport(ERROR, + (errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE), + errmsg("timestamps cannot be binned into infinite intervals"))); + if (stride->month != 0) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), @@ -4393,6 +4942,12 @@ interval_trunc(PG_FUNCTION_ARGS) result = (Interval *) palloc(sizeof(Interval)); + if (INTERVAL_NOT_FINITE(interval)) + { + memcpy(result, interval, sizeof(Interval)); + PG_RETURN_INTERVAL_P(result); + } + lowunits = downcase_truncate_identifier(VARDATA_ANY(units), VARSIZE_ANY_EXHDR(units), false); @@ -4737,7 +5292,7 @@ timestamp_part_common(PG_FUNCTION_ARGS, bool retnumeric) TIMESTAMP_IS_NOBEGIN(timestamp), false); - if (r) + if (r != 0.0) { if (retnumeric) { @@ -5011,7 +5566,7 @@ timestamptz_part_common(PG_FUNCTION_ARGS, bool retnumeric) TIMESTAMP_IS_NOBEGIN(timestamp), true); - if (r) + if (r != 0.0) { if (retnumeric) { @@ -5251,6 +5806,58 @@ extract_timestamptz(PG_FUNCTION_ARGS) return timestamptz_part_common(fcinfo, true); } +/* + * NonFiniteIntervalPart + * + * Used by interval_part when extracting from infinite interval. 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 +NonFiniteIntervalPart(int type, int unit, char *lowunits, bool isNegative) +{ + if ((type != UNITS) && (type != RESERV)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("unit \"%s\" not recognized for type %s", + lowunits, format_type_be(INTERVALOID)))); + + switch (unit) + { + /* Oscillating units */ + case DTK_MICROSEC: + case DTK_MILLISEC: + case DTK_SECOND: + case DTK_MINUTE: + case DTK_MONTH: + case DTK_QUARTER: + return 0.0; + + /* Monotonically-increasing units */ + case DTK_HOUR: + case DTK_DAY: + case DTK_YEAR: + case DTK_DECADE: + case DTK_CENTURY: + case DTK_MILLENNIUM: + case DTK_EPOCH: + if (isNegative) + return -get_float8_infinity(); + else + return get_float8_infinity(); + + default: + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("unit \"%s\" not supported for type %s", + lowunits, format_type_be(INTERVALOID)))); + return 0.0; /* keep compiler quiet */ + } +} /* interval_part() and extract_interval() * Extract specified field from interval. @@ -5275,6 +5882,33 @@ interval_part_common(PG_FUNCTION_ARGS, bool retnumeric) if (type == UNKNOWN_FIELD) type = DecodeSpecial(0, lowunits, &val); + if (INTERVAL_NOT_FINITE(interval)) + { + double r = NonFiniteIntervalPart(type, val, lowunits, + INTERVAL_IS_NOBEGIN(interval)); + + if (r != 0.0) + { + if (retnumeric) + { + if (r < 0) + return DirectFunctionCall3(numeric_in, + CStringGetDatum("-Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1)); + else if (r > 0) + return DirectFunctionCall3(numeric_in, + CStringGetDatum("Infinity"), + ObjectIdGetDatum(InvalidOid), + Int32GetDatum(-1)); + } + else + PG_RETURN_FLOAT8(r); + } + else + PG_RETURN_NULL(); + } + if (type == UNITS) { interval2itm(*interval, tm); @@ -5517,6 +6151,13 @@ timestamp_izone(PG_FUNCTION_ARGS) if (TIMESTAMP_NOT_FINITE(timestamp)) PG_RETURN_TIMESTAMPTZ(timestamp); + if (INTERVAL_NOT_FINITE(zone)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("interval time zone \"%s\" must be finite", + DatumGetCString(DirectFunctionCall1(interval_out, + PointerGetDatum(zone)))))); + if (zone->month != 0 || zone->day != 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), @@ -5747,6 +6388,13 @@ timestamptz_izone(PG_FUNCTION_ARGS) if (TIMESTAMP_NOT_FINITE(timestamp)) PG_RETURN_TIMESTAMP(timestamp); + if (INTERVAL_NOT_FINITE(zone)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("interval time zone \"%s\" must be finite", + DatumGetCString(DirectFunctionCall1(interval_out, + PointerGetDatum(zone)))))); + if (zone->month != 0 || zone->day != 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), @@ -5783,7 +6431,6 @@ generate_series_timestamp(PG_FUNCTION_ARGS) Timestamp finish = PG_GETARG_TIMESTAMP(1); Interval *step = PG_GETARG_INTERVAL_P(2); MemoryContext oldcontext; - const Interval interval_zero = {0}; /* create a function context for cross-call persistence */ funcctx = SRF_FIRSTCALL_INIT(); @@ -5806,13 +6453,18 @@ generate_series_timestamp(PG_FUNCTION_ARGS) fctx->step = *step; /* Determine sign of the interval */ - fctx->step_sign = interval_cmp_internal(&fctx->step, &interval_zero); + fctx->step_sign = interval_sign(&fctx->step); if (fctx->step_sign == 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), errmsg("step size cannot equal zero"))); + if (INTERVAL_NOT_FINITE((&fctx->step))) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("step size cannot be infinite"))); + funcctx->user_fctx = fctx; MemoryContextSwitchTo(oldcontext); } @@ -5864,7 +6516,6 @@ generate_series_timestamptz_internal(FunctionCallInfo fcinfo) Interval *step = PG_GETARG_INTERVAL_P(2); text *zone = (PG_NARGS() == 4) ? PG_GETARG_TEXT_PP(3) : NULL; MemoryContext oldcontext; - const Interval interval_zero = {0}; /* create a function context for cross-call persistence */ funcctx = SRF_FIRSTCALL_INIT(); @@ -5888,13 +6539,18 @@ generate_series_timestamptz_internal(FunctionCallInfo fcinfo) fctx->attimezone = zone ? lookup_timezone(zone) : session_timezone; /* Determine sign of the interval */ - fctx->step_sign = interval_cmp_internal(&fctx->step, &interval_zero); + fctx->step_sign = interval_sign(&fctx->step); if (fctx->step_sign == 0) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), errmsg("step size cannot equal zero"))); + if (INTERVAL_NOT_FINITE((&fctx->step))) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("step size cannot be infinite"))); + funcctx->user_fctx = fctx; MemoryContextSwitchTo(oldcontext); } diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index f2af8eb0dc..cbc719be43 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -57,6 +57,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 202311141 +#define CATALOG_VERSION_NO 202311142 #endif diff --git a/src/include/catalog/pg_aggregate.dat b/src/include/catalog/pg_aggregate.dat index 1bc1d97d74..e1a17cddd8 100644 --- a/src/include/catalog/pg_aggregate.dat +++ b/src/include/catalog/pg_aggregate.dat @@ -43,12 +43,13 @@ { aggfnoid => 'avg(float8)', aggtransfn => 'float8_accum', aggfinalfn => 'float8_avg', aggcombinefn => 'float8_combine', aggtranstype => '_float8', agginitval => '{0,0,0}' }, -{ aggfnoid => 'avg(interval)', aggtransfn => 'interval_accum', - aggfinalfn => 'interval_avg', aggcombinefn => 'interval_combine', - aggmtransfn => 'interval_accum', aggminvtransfn => 'interval_accum_inv', - aggmfinalfn => 'interval_avg', aggtranstype => '_interval', - aggmtranstype => '_interval', agginitval => '{0 second,0 second}', - aggminitval => '{0 second,0 second}' }, +{ aggfnoid => 'avg(interval)', aggtransfn => 'interval_avg_accum', + aggfinalfn => 'interval_avg', aggcombinefn => 'interval_avg_combine', + aggserialfn => 'interval_avg_serialize', + aggdeserialfn => 'interval_avg_deserialize', + aggmtransfn => 'interval_avg_accum', aggminvtransfn => 'interval_avg_accum_inv', + aggmfinalfn => 'interval_avg', aggtranstype => 'internal', + aggtransspace => '40', aggmtranstype => 'internal', aggmtransspace => '40' }, # sum { aggfnoid => 'sum(int8)', aggtransfn => 'int8_avg_accum', @@ -72,10 +73,13 @@ { aggfnoid => 'sum(money)', aggtransfn => 'cash_pl', aggcombinefn => 'cash_pl', aggmtransfn => 'cash_pl', aggminvtransfn => 'cash_mi', aggtranstype => 'money', aggmtranstype => 'money' }, -{ aggfnoid => 'sum(interval)', aggtransfn => 'interval_pl', - aggcombinefn => 'interval_pl', aggmtransfn => 'interval_pl', - aggminvtransfn => 'interval_mi', aggtranstype => 'interval', - aggmtranstype => 'interval' }, +{ aggfnoid => 'sum(interval)', aggtransfn => 'interval_avg_accum', + aggfinalfn => 'interval_sum', aggcombinefn => 'interval_avg_combine', + aggserialfn => 'interval_avg_serialize', + aggdeserialfn => 'interval_avg_deserialize', + aggmtransfn => 'interval_avg_accum', aggminvtransfn => 'interval_avg_accum_inv', + aggmfinalfn => 'interval_sum', aggtranstype => 'internal', + aggtransspace => '40', aggmtranstype => 'internal', aggmtransspace => '40'}, { aggfnoid => 'sum(numeric)', aggtransfn => 'numeric_avg_accum', aggfinalfn => 'numeric_sum', aggcombinefn => 'numeric_avg_combine', aggserialfn => 'numeric_avg_serialize', diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index ee351bb762..fb58dee3bc 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -4917,17 +4917,29 @@ prosrc => 'numeric_poly_stddev_samp' }, { oid => '1843', descr => 'aggregate transition function', - proname => 'interval_accum', prorettype => '_interval', - proargtypes => '_interval interval', prosrc => 'interval_accum' }, + proname => 'interval_avg_accum', proisstrict => 'f', + prorettype => 'internal', proargtypes => 'internal interval', + prosrc => 'interval_avg_accum' }, { oid => '3325', descr => 'aggregate combine function', - proname => 'interval_combine', prorettype => '_interval', - proargtypes => '_interval _interval', prosrc => 'interval_combine' }, + proname => 'interval_avg_combine', proisstrict => 'f', + prorettype => 'internal', proargtypes => 'internal internal', + prosrc => 'interval_avg_combine' }, { oid => '3549', descr => 'aggregate transition function', - proname => 'interval_accum_inv', prorettype => '_interval', - proargtypes => '_interval interval', prosrc => 'interval_accum_inv' }, + proname => 'interval_avg_accum_inv', proisstrict => 'f', + prorettype => 'internal', proargtypes => 'internal interval', + prosrc => 'interval_avg_accum_inv' }, +{ oid => '8505', descr => 'aggregate serial function', + proname => 'interval_avg_serialize', prorettype => 'bytea', + proargtypes => 'internal', prosrc => 'interval_avg_serialize' }, +{ oid => '8506', descr => 'aggregate deserial function', + proname => 'interval_avg_deserialize', prorettype => 'internal', + proargtypes => 'bytea internal', prosrc => 'interval_avg_deserialize' }, { oid => '1844', descr => 'aggregate final function', - proname => 'interval_avg', prorettype => 'interval', - proargtypes => '_interval', prosrc => 'interval_avg' }, + proname => 'interval_avg', proisstrict => 'f', prorettype => 'interval', + proargtypes => 'internal', prosrc => 'interval_avg' }, +{ oid => '8507', descr => 'aggregate final function', + proname => 'interval_sum', proisstrict => 'f', prorettype => 'interval', + proargtypes => 'internal', prosrc => 'interval_sum' }, { oid => '1962', descr => 'aggregate transition function', proname => 'int2_avg_accum', prorettype => '_int8', proargtypes => '_int8 int2', prosrc => 'int2_avg_accum' }, diff --git a/src/include/datatype/timestamp.h b/src/include/datatype/timestamp.h index 1a6390585c..b63acc0a2f 100644 --- a/src/include/datatype/timestamp.h +++ b/src/include/datatype/timestamp.h @@ -151,7 +151,7 @@ struct pg_itm_in #define TIMESTAMP_INFINITY PG_INT64_MAX /* - * Historically these alias for infinity have been used. + * Historically these aliases for infinity have been used. */ #define DT_NOBEGIN TIMESTAMP_MINUS_INFINITY #define DT_NOEND TIMESTAMP_INFINITY @@ -168,6 +168,31 @@ struct pg_itm_in #define TIMESTAMP_NOT_FINITE(j) (TIMESTAMP_IS_NOBEGIN(j) || TIMESTAMP_IS_NOEND(j)) +/* + * Infinite intervals are represented by setting all fields to the minimum or + * maximum integer values. + */ +#define INTERVAL_NOBEGIN(i) \ + do { \ + (i)->time = PG_INT64_MIN; \ + (i)->day = PG_INT32_MIN; \ + (i)->month = PG_INT32_MIN; \ + } while (0) + +#define INTERVAL_IS_NOBEGIN(i) \ + ((i)->month == PG_INT32_MIN && (i)->day == PG_INT32_MIN && (i)->time == PG_INT64_MIN) + +#define INTERVAL_NOEND(i) \ + do { \ + (i)->time = PG_INT64_MAX; \ + (i)->day = PG_INT32_MAX; \ + (i)->month = PG_INT32_MAX; \ + } while (0) + +#define INTERVAL_IS_NOEND(i) \ + ((i)->month == PG_INT32_MAX && (i)->day == PG_INT32_MAX && (i)->time == PG_INT64_MAX) + +#define INTERVAL_NOT_FINITE(i) (INTERVAL_IS_NOBEGIN(i) || INTERVAL_IS_NOEND(i)) /* * Julian date support. diff --git a/src/test/regress/expected/brin_multi.out b/src/test/regress/expected/brin_multi.out index 80801cd4ee..8f4c95b9e6 100644 --- a/src/test/regress/expected/brin_multi.out +++ b/src/test/regress/expected/brin_multi.out @@ -941,6 +941,34 @@ SELECT * FROM brin_interval_test WHERE a = '30 years'::interval; Index Cond: (a = '@ 30 years'::interval) (4 rows) +DROP TABLE brin_interval_test; +RESET enable_seqscan; +-- test handling of infinite interval values +CREATE TABLE brin_interval_test(a INTERVAL); +INSERT INTO brin_interval_test VALUES ('-infinity'), ('infinity'); +INSERT INTO brin_interval_test SELECT (i || ' days')::interval FROM generate_series(100, 140) s(i); +CREATE INDEX ON brin_interval_test USING brin (a interval_minmax_multi_ops) WITH (pages_per_range=1); +SET enable_seqscan = off; +EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF) +SELECT * FROM brin_interval_test WHERE a = '-30 years'::interval; + QUERY PLAN +----------------------------------------------------------------------------- + Bitmap Heap Scan on brin_interval_test (actual rows=0 loops=1) + Recheck Cond: (a = '@ 30 years ago'::interval) + -> Bitmap Index Scan on brin_interval_test_a_idx (actual rows=0 loops=1) + Index Cond: (a = '@ 30 years ago'::interval) +(4 rows) + +EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF) +SELECT * FROM brin_interval_test WHERE a = '30 years'::interval; + QUERY PLAN +----------------------------------------------------------------------------- + Bitmap Heap Scan on brin_interval_test (actual rows=0 loops=1) + Recheck Cond: (a = '@ 30 years'::interval) + -> Bitmap Index Scan on brin_interval_test_a_idx (actual rows=0 loops=1) + Index Cond: (a = '@ 30 years'::interval) +(4 rows) + DROP TABLE brin_interval_test; RESET enable_seqscan; RESET datestyle; diff --git a/src/test/regress/expected/horology.out b/src/test/regress/expected/horology.out index 8f52661096..cfb4b205e4 100644 --- a/src/test/regress/expected/horology.out +++ b/src/test/regress/expected/horology.out @@ -1171,6 +1171,7 @@ SELECT t.d1 AS t, i.f1 AS i, t.d1 + i.f1 AS "add", t.d1 - i.f1 AS "subtract" SELECT t.f1 AS t, i.f1 AS i, t.f1 + i.f1 AS "add", t.f1 - i.f1 AS "subtract" FROM TIME_TBL t, INTERVAL_TBL i + WHERE isfinite(i.f1) ORDER BY 1,2; t | i | add | subtract -------------+-------------------------------+-------------+------------- @@ -1278,6 +1279,7 @@ SELECT t.f1 AS t, i.f1 AS i, t.f1 + i.f1 AS "add", t.f1 - i.f1 AS "subtract" SELECT t.f1 AS t, i.f1 AS i, t.f1 + i.f1 AS "add", t.f1 - i.f1 AS "subtract" FROM TIMETZ_TBL t, INTERVAL_TBL i + WHERE isfinite(i.f1) ORDER BY 1,2; t | i | add | subtract ----------------+-------------------------------+----------------+---------------- @@ -1556,6 +1558,22 @@ SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 + t.f1 AS plus ORDER BY plus, "timestamp", "interval"; timestamp | interval | plus ------------------------------+-------------------------------+------------------------------ + Thu Jan 01 00:00:00 1970 PST | -infinity | -infinity + Wed Feb 28 17:32:01 1996 PST | -infinity | -infinity + Thu Feb 29 17:32:01 1996 PST | -infinity | -infinity + Fri Mar 01 17:32:01 1996 PST | -infinity | -infinity + Mon Dec 30 17:32:01 1996 PST | -infinity | -infinity + Tue Dec 31 17:32:01 1996 PST | -infinity | -infinity + Fri Dec 31 17:32:01 1999 PST | -infinity | -infinity + Sat Jan 01 17:32:01 2000 PST | -infinity | -infinity + Wed Mar 15 02:14:05 2000 PST | -infinity | -infinity + Wed Mar 15 03:14:04 2000 PST | -infinity | -infinity + Wed Mar 15 08:14:01 2000 PST | -infinity | -infinity + Wed Mar 15 12:14:03 2000 PST | -infinity | -infinity + Wed Mar 15 13:14:02 2000 PST | -infinity | -infinity + Sun Dec 31 17:32:01 2000 PST | -infinity | -infinity + Mon Jan 01 17:32:01 2001 PST | -infinity | -infinity + Sat Sep 22 18:19:20 2001 PDT | -infinity | -infinity Thu Jan 01 00:00:00 1970 PST | @ 14 secs ago | Wed Dec 31 23:59:46 1969 PST Thu Jan 01 00:00:00 1970 PST | @ 1 min | Thu Jan 01 00:01:00 1970 PST Thu Jan 01 00:00:00 1970 PST | @ 5 hours | Thu Jan 01 05:00:00 1970 PST @@ -1716,14 +1734,45 @@ SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 + t.f1 AS plus Sun Dec 31 17:32:01 2000 PST | @ 34 years | Sun Dec 31 17:32:01 2034 PST Mon Jan 01 17:32:01 2001 PST | @ 34 years | Mon Jan 01 17:32:01 2035 PST Sat Sep 22 18:19:20 2001 PDT | @ 34 years | Sat Sep 22 18:19:20 2035 PDT -(160 rows) + Thu Jan 01 00:00:00 1970 PST | infinity | infinity + Wed Feb 28 17:32:01 1996 PST | infinity | infinity + Thu Feb 29 17:32:01 1996 PST | infinity | infinity + Fri Mar 01 17:32:01 1996 PST | infinity | infinity + Mon Dec 30 17:32:01 1996 PST | infinity | infinity + Tue Dec 31 17:32:01 1996 PST | infinity | infinity + Fri Dec 31 17:32:01 1999 PST | infinity | infinity + Sat Jan 01 17:32:01 2000 PST | infinity | infinity + Wed Mar 15 02:14:05 2000 PST | infinity | infinity + Wed Mar 15 03:14:04 2000 PST | infinity | infinity + Wed Mar 15 08:14:01 2000 PST | infinity | infinity + Wed Mar 15 12:14:03 2000 PST | infinity | infinity + Wed Mar 15 13:14:02 2000 PST | infinity | infinity + Sun Dec 31 17:32:01 2000 PST | infinity | infinity + Mon Jan 01 17:32:01 2001 PST | infinity | infinity + Sat Sep 22 18:19:20 2001 PDT | infinity | infinity +(192 rows) SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 - t.f1 AS minus FROM TEMP_TIMESTAMP d, INTERVAL_TBL t - WHERE isfinite(d.f1) ORDER BY minus, "timestamp", "interval"; timestamp | interval | minus ------------------------------+-------------------------------+------------------------------ + Thu Jan 01 00:00:00 1970 PST | infinity | -infinity + Wed Feb 28 17:32:01 1996 PST | infinity | -infinity + Thu Feb 29 17:32:01 1996 PST | infinity | -infinity + Fri Mar 01 17:32:01 1996 PST | infinity | -infinity + Mon Dec 30 17:32:01 1996 PST | infinity | -infinity + Tue Dec 31 17:32:01 1996 PST | infinity | -infinity + Fri Dec 31 17:32:01 1999 PST | infinity | -infinity + Sat Jan 01 17:32:01 2000 PST | infinity | -infinity + Wed Mar 15 02:14:05 2000 PST | infinity | -infinity + Wed Mar 15 03:14:04 2000 PST | infinity | -infinity + Wed Mar 15 08:14:01 2000 PST | infinity | -infinity + Wed Mar 15 12:14:03 2000 PST | infinity | -infinity + Wed Mar 15 13:14:02 2000 PST | infinity | -infinity + Sun Dec 31 17:32:01 2000 PST | infinity | -infinity + Mon Jan 01 17:32:01 2001 PST | infinity | -infinity + Sat Sep 22 18:19:20 2001 PDT | infinity | -infinity Thu Jan 01 00:00:00 1970 PST | @ 34 years | Wed Jan 01 00:00:00 1936 PST Wed Feb 28 17:32:01 1996 PST | @ 34 years | Wed Feb 28 17:32:01 1962 PST Thu Feb 29 17:32:01 1996 PST | @ 34 years | Wed Feb 28 17:32:01 1962 PST @@ -1884,7 +1933,23 @@ SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 - t.f1 AS minus Sat Sep 22 18:19:20 2001 PDT | @ 5 hours | Sat Sep 22 13:19:20 2001 PDT Sat Sep 22 18:19:20 2001 PDT | @ 1 min | Sat Sep 22 18:18:20 2001 PDT Sat Sep 22 18:19:20 2001 PDT | @ 14 secs ago | Sat Sep 22 18:19:34 2001 PDT -(160 rows) + Thu Jan 01 00:00:00 1970 PST | -infinity | infinity + Wed Feb 28 17:32:01 1996 PST | -infinity | infinity + Thu Feb 29 17:32:01 1996 PST | -infinity | infinity + Fri Mar 01 17:32:01 1996 PST | -infinity | infinity + Mon Dec 30 17:32:01 1996 PST | -infinity | infinity + Tue Dec 31 17:32:01 1996 PST | -infinity | infinity + Fri Dec 31 17:32:01 1999 PST | -infinity | infinity + Sat Jan 01 17:32:01 2000 PST | -infinity | infinity + Wed Mar 15 02:14:05 2000 PST | -infinity | infinity + Wed Mar 15 03:14:04 2000 PST | -infinity | infinity + Wed Mar 15 08:14:01 2000 PST | -infinity | infinity + Wed Mar 15 12:14:03 2000 PST | -infinity | infinity + Wed Mar 15 13:14:02 2000 PST | -infinity | infinity + Sun Dec 31 17:32:01 2000 PST | -infinity | infinity + Mon Jan 01 17:32:01 2001 PST | -infinity | infinity + Sat Sep 22 18:19:20 2001 PDT | -infinity | infinity +(192 rows) SELECT d.f1 AS "timestamp", timestamp with time zone '1980-01-06 00:00 GMT' AS gpstime_zero, diff --git a/src/test/regress/expected/interval.out b/src/test/regress/expected/interval.out index 75d19d6594..a481781475 100644 --- a/src/test/regress/expected/interval.out +++ b/src/test/regress/expected/interval.out @@ -52,6 +52,18 @@ SELECT INTERVAL '10 years -11 month -12 days +13:14' AS "9 years..."; 9 years 1 mon -12 days +13:14:00 (1 row) +SELECT INTERVAL 'infinity' AS "eternity"; + eternity +---------- + infinity +(1 row) + +SELECT INTERVAL '-infinity' AS "beginning of time"; + beginning of time +------------------- + -infinity +(1 row) + CREATE TABLE INTERVAL_TBL (f1 interval); INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 1 minute'); INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 5 hour'); @@ -63,6 +75,8 @@ INSERT INTO INTERVAL_TBL (f1) VALUES ('1 day 2 hours 3 minutes 4 seconds'); INSERT INTO INTERVAL_TBL (f1) VALUES ('6 years'); INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months'); INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months 12 hours'); +INSERT INTO INTERVAL_TBL (f1) VALUES ('infinity'); +INSERT INTO INTERVAL_TBL (f1) VALUES ('-infinity'); -- badly formatted interval INSERT INTO INTERVAL_TBL (f1) VALUES ('badly formatted interval'); ERROR: invalid input syntax for type interval: "badly formatted interval" @@ -117,7 +131,9 @@ SELECT * FROM INTERVAL_TBL; 6 years 5 mons 5 mons 12:00:00 -(10 rows) + infinity + -infinity +(12 rows) SELECT * FROM INTERVAL_TBL WHERE INTERVAL_TBL.f1 <> interval '@ 10 days'; @@ -132,7 +148,9 @@ SELECT * FROM INTERVAL_TBL 6 years 5 mons 5 mons 12:00:00 -(9 rows) + infinity + -infinity +(11 rows) SELECT * FROM INTERVAL_TBL WHERE INTERVAL_TBL.f1 <= interval '@ 5 hours'; @@ -141,7 +159,8 @@ SELECT * FROM INTERVAL_TBL 00:01:00 05:00:00 -00:00:14 -(3 rows) + -infinity +(4 rows) SELECT * FROM INTERVAL_TBL WHERE INTERVAL_TBL.f1 < interval '@ 1 day'; @@ -150,7 +169,8 @@ SELECT * FROM INTERVAL_TBL 00:01:00 05:00:00 -00:00:14 -(3 rows) + -infinity +(4 rows) SELECT * FROM INTERVAL_TBL WHERE INTERVAL_TBL.f1 = interval '@ 34 years'; @@ -168,7 +188,8 @@ SELECT * FROM INTERVAL_TBL 6 years 5 mons 5 mons 12:00:00 -(5 rows) + infinity +(6 rows) SELECT * FROM INTERVAL_TBL WHERE INTERVAL_TBL.f1 > interval '@ 3 seconds ago'; @@ -183,7 +204,8 @@ SELECT * FROM INTERVAL_TBL 6 years 5 mons 5 mons 12:00:00 -(9 rows) + infinity +(10 rows) SELECT r1.*, r2.* FROM INTERVAL_TBL r1, INTERVAL_TBL r2 @@ -191,27 +213,35 @@ SELECT r1.*, r2.* ORDER BY r1.f1, r2.f1; f1 | f1 -----------------+----------------- + -00:00:14 | -infinity + 00:01:00 | -infinity 00:01:00 | -00:00:14 + 05:00:00 | -infinity 05:00:00 | -00:00:14 05:00:00 | 00:01:00 + 1 day 02:03:04 | -infinity 1 day 02:03:04 | -00:00:14 1 day 02:03:04 | 00:01:00 1 day 02:03:04 | 05:00:00 + 10 days | -infinity 10 days | -00:00:14 10 days | 00:01:00 10 days | 05:00:00 10 days | 1 day 02:03:04 + 3 mons | -infinity 3 mons | -00:00:14 3 mons | 00:01:00 3 mons | 05:00:00 3 mons | 1 day 02:03:04 3 mons | 10 days + 5 mons | -infinity 5 mons | -00:00:14 5 mons | 00:01:00 5 mons | 05:00:00 5 mons | 1 day 02:03:04 5 mons | 10 days 5 mons | 3 mons + 5 mons 12:00:00 | -infinity 5 mons 12:00:00 | -00:00:14 5 mons 12:00:00 | 00:01:00 5 mons 12:00:00 | 05:00:00 @@ -219,6 +249,7 @@ SELECT r1.*, r2.* 5 mons 12:00:00 | 10 days 5 mons 12:00:00 | 3 mons 5 mons 12:00:00 | 5 mons + 6 years | -infinity 6 years | -00:00:14 6 years | 00:01:00 6 years | 05:00:00 @@ -227,6 +258,7 @@ SELECT r1.*, r2.* 6 years | 3 mons 6 years | 5 mons 6 years | 5 mons 12:00:00 + 34 years | -infinity 34 years | -00:00:14 34 years | 00:01:00 34 years | 05:00:00 @@ -236,8 +268,63 @@ SELECT r1.*, r2.* 34 years | 5 mons 34 years | 5 mons 12:00:00 34 years | 6 years -(45 rows) + infinity | -infinity + infinity | -00:00:14 + infinity | 00:01:00 + infinity | 05:00:00 + infinity | 1 day 02:03:04 + infinity | 10 days + infinity | 3 mons + infinity | 5 mons + infinity | 5 mons 12:00:00 + infinity | 6 years + infinity | 34 years +(66 rows) +-- test unary minus +SELECT f1, -f1 FROM INTERVAL_TBL; + f1 | ?column? +-----------------+------------------- + 00:01:00 | -00:01:00 + 05:00:00 | -05:00:00 + 10 days | -10 days + 34 years | -34 years + 3 mons | -3 mons + -00:00:14 | 00:00:14 + 1 day 02:03:04 | -1 days -02:03:04 + 6 years | -6 years + 5 mons | -5 mons + 5 mons 12:00:00 | -5 mons -12:00:00 + infinity | -infinity + -infinity | infinity +(12 rows) + +SELECT -('-2147483648 months'::interval); -- should fail +ERROR: interval out of range +SELECT -('-2147483647 months'::interval); -- ok + ?column? +------------------------ + 178956970 years 7 mons +(1 row) + +SELECT -('-2147483648 days'::interval); -- should fail +ERROR: interval out of range +SELECT -('-2147483647 days'::interval); -- ok + ?column? +----------------- + 2147483647 days +(1 row) + +SELECT -('-9223372036854775808 us'::interval); -- should fail +ERROR: interval out of range +SELECT -('-9223372036854775807 us'::interval); -- ok + ?column? +------------------------- + 2562047788:00:54.775807 +(1 row) + +SELECT -('-2147483647 months -2147483647 days -9223372036854775807 us'::interval); -- should fail +ERROR: interval out of range -- Test intervals that are large enough to overflow 64 bits in comparisons CREATE TEMP TABLE INTERVAL_TBL_OF (f1 interval); INSERT INTO INTERVAL_TBL_OF (f1) VALUES @@ -304,6 +391,17 @@ SELECT f1 FROM INTERVAL_TBL_OF r1 ORDER BY f1; (5 rows) RESET enable_seqscan; +-- subtracting about-to-overflow values should result in 0 +SELECT f1 - f1 FROM INTERVAL_TBL_OF; + ?column? +---------- + 00:00:00 + 00:00:00 + 00:00:00 + 00:00:00 + 00:00:00 +(5 rows) + DROP TABLE INTERVAL_TBL_OF; -- Test multiplication and division with intervals. -- Floating point arithmetic rounding errors can lead to unexpected results, @@ -386,12 +484,14 @@ SELECT * FROM INTERVAL_TBL; @ 6 years @ 5 mons @ 5 mons 12 hours -(10 rows) + infinity + -infinity +(12 rows) -- test avg(interval), which is somewhat fragile since people have been -- known to change the allowed input syntax for type interval without -- updating pg_aggregate.agginitval -select avg(f1) from interval_tbl; +select avg(f1) from interval_tbl where isfinite(f1); avg ------------------------------------------------- @ 4 years 1 mon 10 days 4 hours 18 mins 23 secs @@ -820,8 +920,8 @@ SELECT interval '1 2:03:04.5678' minute to second(2); SELECT f1, f1::INTERVAL DAY TO MINUTE AS "minutes", (f1 + INTERVAL '1 month')::INTERVAL MONTH::INTERVAL YEAR AS "years" FROM interval_tbl; - f1 | minutes | years ------------------+-----------------+---------- + f1 | minutes | years +-----------------+-----------------+----------- 00:01:00 | 00:01:00 | 00:00:00 05:00:00 | 05:00:00 | 00:00:00 10 days | 10 days | 00:00:00 @@ -832,7 +932,9 @@ SELECT f1, f1::INTERVAL DAY TO MINUTE AS "minutes", 6 years | 6 years | 6 years 5 mons | 5 mons | 00:00:00 5 mons 12:00:00 | 5 mons 12:00:00 | 00:00:00 -(10 rows) + infinity | infinity | infinity + -infinity | -infinity | -infinity +(12 rows) -- test inputting and outputting SQL standard interval literals SET IntervalStyle TO sql_standard; @@ -1616,31 +1718,31 @@ select make_interval(mins := -1, secs := -9223372036800.0); ERROR: interval out of range -- test that INT_MIN number is formatted properly SET IntervalStyle to postgres; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; interval -------------------------------------------------------------------- - -178956970 years -8 mons -2147483648 days -2562047788:00:54.775808 + -178956970 years -7 mons -2147483648 days -2562047788:00:54.775808 (1 row) SET IntervalStyle to sql_standard; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; interval --------------------------------------------------- - -178956970-8 -2147483648 -2562047788:00:54.775808 + -178956970-7 -2147483648 -2562047788:00:54.775808 (1 row) SET IntervalStyle to iso_8601; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; interval ----------------------------------------------------- - P-178956970Y-8M-2147483648DT-2562047788H-54.775808S + P-178956970Y-7M-2147483648DT-2562047788H-54.775808S (1 row) SET IntervalStyle to postgres_verbose; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; interval ------------------------------------------------------------------------------ - @ 178956970 years 8 mons 2147483648 days 2562047788 hours 54.775808 secs ago + @ 178956970 years 7 mons 2147483648 days 2562047788 hours 54.775808 secs ago (1 row) -- check that '30 days' equals '1 month' according to the hash function @@ -1719,19 +1821,21 @@ 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.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 | 1072958400.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 | 189345600.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) + 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 | 1072958400.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 | 189345600.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 + infinity | | | | | Infinity | Infinity | | | Infinity | Infinity | Infinity | Infinity | Infinity + -infinity | | | | | -Infinity | -Infinity | | | -Infinity | -Infinity | -Infinity | -Infinity | -Infinity +(12 rows) SELECT EXTRACT(FORTNIGHT FROM INTERVAL '2 days'); -- error ERROR: unit "fortnight" not recognized for type interval @@ -1805,7 +1909,9 @@ SELECT f1, @ 6 years | 0 | 0 | 0 | 189345600 @ 5 mons | 0 | 0 | 0 | 12960000 @ 5 mons 12 hours | 0 | 0 | 0 | 13003200 -(10 rows) + infinity | | | | Infinity + -infinity | | | | -Infinity +(12 rows) -- internal overflow test case SELECT extract(epoch from interval '1000000000 days'); @@ -1814,6 +1920,292 @@ SELECT extract(epoch from interval '1000000000 days'); 86400000000000.000000 (1 row) +-- +-- test infinite intervals +-- +-- largest finite intervals +SELECT interval '-2147483648 months -2147483648 days -9223372036854775807 us'; + interval +------------------------------------------------------------------------------ + @ 178956970 years 8 mons 2147483648 days 2562047788 hours 54.775807 secs ago +(1 row) + +SELECT interval '2147483647 months 2147483647 days 9223372036854775806 us'; + interval +-------------------------------------------------------------------------- + @ 178956970 years 7 mons 2147483647 days 2562047788 hours 54.775806 secs +(1 row) + +-- infinite intervals +SELECT interval '-2147483648 months -2147483648 days -9223372036854775808 us'; + interval +----------- + -infinity +(1 row) + +SELECT interval '2147483647 months 2147483647 days 9223372036854775807 us'; + interval +---------- + infinity +(1 row) + +CREATE TABLE INFINITE_INTERVAL_TBL (i interval); +INSERT INTO INFINITE_INTERVAL_TBL VALUES ('infinity'), ('-infinity'), ('1 year 2 days 3 hours'); +SELECT i, isfinite(i) FROM INFINITE_INTERVAL_TBL; + i | isfinite +-------------------------+---------- + infinity | f + -infinity | f + @ 1 year 2 days 3 hours | t +(3 rows) + +-- test basic arithmetic +CREATE FUNCTION eval(expr text) +RETURNS text AS +$$ +DECLARE + result text; +BEGIN + EXECUTE 'select '||expr INTO result; + RETURN result; +EXCEPTION WHEN OTHERS THEN + RETURN SQLERRM; +END +$$ +LANGUAGE plpgsql; +SELECT d AS date, i AS interval, + eval(format('date %L + interval %L', d, i)) AS plus, + eval(format('date %L - interval %L', d, i)) AS minus +FROM (VALUES (date '-infinity'), + (date '1995-08-06'), + (date 'infinity')) AS t1(d), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + date | interval | plus | minus +------------+-----------+------------------------+------------------------ + -infinity | -infinity | -infinity | timestamp out of range + -infinity | infinity | timestamp out of range | -infinity + 1995-08-06 | -infinity | -infinity | infinity + 1995-08-06 | infinity | infinity | -infinity + infinity | -infinity | timestamp out of range | infinity + infinity | infinity | infinity | timestamp out of range +(6 rows) + +SELECT i1 AS interval1, i2 AS interval2, + eval(format('interval %L + interval %L', i1, i2)) AS plus, + eval(format('interval %L - interval %L', i1, i2)) AS minus +FROM (VALUES (interval '-infinity'), + (interval '2 months'), + (interval 'infinity')) AS t1(i1), + (VALUES (interval '-infinity'), + (interval '10 days'), + (interval 'infinity')) AS t2(i2); + interval1 | interval2 | plus | minus +-----------+-----------+-----------------------+----------------------- + -infinity | -infinity | -infinity | interval out of range + -infinity | @ 10 days | -infinity | -infinity + -infinity | infinity | interval out of range | -infinity + @ 2 mons | -infinity | -infinity | infinity + @ 2 mons | @ 10 days | @ 2 mons 10 days | @ 2 mons -10 days + @ 2 mons | infinity | infinity | -infinity + infinity | -infinity | interval out of range | infinity + infinity | @ 10 days | infinity | infinity + infinity | infinity | infinity | interval out of range +(9 rows) + +SELECT interval '2147483646 months 2147483646 days 9223372036854775806 us' + interval '1 month 1 day 1 us'; +ERROR: interval out of range +SELECT interval '-2147483647 months -2147483647 days -9223372036854775807 us' + interval '-1 month -1 day -1 us'; +ERROR: interval out of range +SELECT interval '2147483646 months 2147483646 days 9223372036854775806 us' - interval '-1 month -1 day -1 us'; +ERROR: interval out of range +SELECT interval '-2147483647 months -2147483647 days -9223372036854775807 us' - interval '1 month 1 day 1 us'; +ERROR: interval out of range +SELECT t AS timestamp, i AS interval, + eval(format('timestamp %L + interval %L', t, i)) AS plus, + eval(format('timestamp %L - interval %L', t, i)) AS minus +FROM (VALUES (timestamp '-infinity'), + (timestamp '1995-08-06 12:30:15'), + (timestamp 'infinity')) AS t1(t), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + timestamp | interval | plus | minus +---------------------+-----------+------------------------+------------------------ + -infinity | -infinity | -infinity | timestamp out of range + -infinity | infinity | timestamp out of range | -infinity + 1995-08-06 12:30:15 | -infinity | -infinity | infinity + 1995-08-06 12:30:15 | infinity | infinity | -infinity + infinity | -infinity | timestamp out of range | infinity + infinity | infinity | infinity | timestamp out of range +(6 rows) + +SELECT t AT TIME ZONE 'GMT' AS timestamptz, i AS interval, + eval(format('timestamptz %L + interval %L', t, i)) AS plus, + eval(format('timestamptz %L - interval %L', t, i)) AS minus +FROM (VALUES (timestamptz '-infinity'), + (timestamptz '1995-08-06 12:30:15 GMT'), + (timestamptz 'infinity')) AS t1(t), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + timestamptz | interval | plus | minus +---------------------+-----------+------------------------+------------------------ + -infinity | -infinity | -infinity | timestamp out of range + -infinity | infinity | timestamp out of range | -infinity + 1995-08-06 12:30:15 | -infinity | -infinity | infinity + 1995-08-06 12:30:15 | infinity | infinity | -infinity + infinity | -infinity | timestamp out of range | infinity + infinity | infinity | infinity | timestamp out of range +(6 rows) + +-- time +/- infinite interval not supported +SELECT time '11:27:42' + interval 'infinity'; +ERROR: cannot add infinite interval to time +SELECT time '11:27:42' + interval '-infinity'; +ERROR: cannot add infinite interval to time +SELECT time '11:27:42' - interval 'infinity'; +ERROR: cannot subtract infinite interval from time +SELECT time '11:27:42' - interval '-infinity'; +ERROR: cannot subtract infinite interval from time +SELECT timetz '11:27:42' + interval 'infinity'; +ERROR: cannot add infinite interval to time +SELECT timetz '11:27:42' + interval '-infinity'; +ERROR: cannot add infinite interval to time +SELECT timetz '11:27:42' - interval 'infinity'; +ERROR: cannot subtract infinite interval from time +SELECT timetz '11:27:42' - interval '-infinity'; +ERROR: cannot subtract infinite interval from time +SELECT lhst.i lhs, + rhst.i rhs, + lhst.i < rhst.i AS lt, + lhst.i <= rhst.i AS le, + lhst.i = rhst.i AS eq, + lhst.i > rhst.i AS gt, + lhst.i >= rhst.i AS ge, + lhst.i <> rhst.i AS ne + FROM INFINITE_INTERVAL_TBL lhst CROSS JOIN INFINITE_INTERVAL_TBL rhst + WHERE NOT isfinite(lhst.i); + lhs | rhs | lt | le | eq | gt | ge | ne +-----------+-------------------------+----+----+----+----+----+---- + infinity | infinity | f | t | t | f | t | f + -infinity | infinity | t | t | f | f | f | t + infinity | -infinity | f | f | f | t | t | t + -infinity | -infinity | f | t | t | f | t | f + infinity | @ 1 year 2 days 3 hours | f | f | f | t | t | t + -infinity | @ 1 year 2 days 3 hours | t | t | f | f | f | t +(6 rows) + +SELECT i AS interval, + -i AS um, + i * 2.0 AS mul, + i * -2.0 AS mul_neg, + i * 'infinity' AS mul_inf, + i * '-infinity' AS mul_inf_neg, + i / 3.0 AS div, + i / -3.0 AS div_neg + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + interval | um | mul | mul_neg | mul_inf | mul_inf_neg | div | div_neg +-----------+-----------+-----------+-----------+-----------+-------------+-----------+----------- + infinity | -infinity | infinity | -infinity | infinity | -infinity | infinity | -infinity + -infinity | infinity | -infinity | infinity | -infinity | infinity | -infinity | infinity +(2 rows) + +SELECT -interval '-2147483647 months -2147483647 days -9223372036854775807 us'; +ERROR: interval out of range +SELECT interval 'infinity' * 'nan'; +ERROR: interval out of range +SELECT interval '-infinity' * 'nan'; +ERROR: interval out of range +SELECT interval '-1073741824 months -1073741824 days -4611686018427387904 us' * 2; +ERROR: interval out of range +SELECT interval 'infinity' * 0; +ERROR: interval out of range +SELECT interval '-infinity' * 0; +ERROR: interval out of range +SELECT interval '0 days' * 'infinity'::float; +ERROR: interval out of range +SELECT interval '0 days' * '-infinity'::float; +ERROR: interval out of range +SELECT interval '5 days' * 'infinity'::float; + ?column? +---------- + infinity +(1 row) + +SELECT interval '5 days' * '-infinity'::float; + ?column? +----------- + -infinity +(1 row) + +SELECT interval 'infinity' / 'infinity'; +ERROR: interval out of range +SELECT interval 'infinity' / '-infinity'; +ERROR: interval out of range +SELECT interval 'infinity' / 'nan'; +ERROR: interval out of range +SELECT interval '-infinity' / 'infinity'; +ERROR: interval out of range +SELECT interval '-infinity' / '-infinity'; +ERROR: interval out of range +SELECT interval '-infinity' / 'nan'; +ERROR: interval out of range +SELECT interval '-1073741824 months -1073741824 days -4611686018427387904 us' / 0.5; +ERROR: interval out of range +SELECT date_bin('infinity', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00'); +ERROR: timestamps cannot be binned into infinite intervals +SELECT date_bin('-infinity', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00'); +ERROR: timestamps cannot be binned into infinite intervals +SELECT i AS interval, date_trunc('hour', i) + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + interval | date_trunc +-----------+------------ + infinity | infinity + -infinity | -infinity +(2 rows) + +SELECT i AS interval, justify_days(i), justify_hours(i), justify_interval(i) + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + interval | justify_days | justify_hours | justify_interval +-----------+--------------+---------------+------------------ + infinity | infinity | infinity | infinity + -infinity | -infinity | -infinity | -infinity +(2 rows) + +SELECT timezone('infinity'::interval, '1995-08-06 12:12:12'::timestamp); +ERROR: interval time zone "infinity" must be finite +SELECT timezone('-infinity'::interval, '1995-08-06 12:12:12'::timestamp); +ERROR: interval time zone "-infinity" must be finite +SELECT timezone('infinity'::interval, '1995-08-06 12:12:12'::timestamptz); +ERROR: interval time zone "infinity" must be finite +SELECT timezone('-infinity'::interval, '1995-08-06 12:12:12'::timestamptz); +ERROR: interval time zone "-infinity" must be finite +SELECT timezone('infinity'::interval, '12:12:12'::time); +ERROR: interval time zone "infinity" must be finite +SELECT timezone('-infinity'::interval, '12:12:12'::time); +ERROR: interval time zone "-infinity" must be finite +SELECT timezone('infinity'::interval, '12:12:12'::timetz); +ERROR: interval time zone "infinity" must be finite +SELECT timezone('-infinity'::interval, '12:12:12'::timetz); +ERROR: interval time zone "-infinity" must be finite +SELECT 'infinity'::interval::time; +ERROR: cannot convert infinite interval to time +SELECT '-infinity'::interval::time; +ERROR: cannot convert infinite interval to time +SELECT to_char('infinity'::interval, 'YYYY'); + to_char +--------- + +(1 row) + +SELECT to_char('-infinity'::interval, 'YYYY'); + to_char +--------- + +(1 row) + -- "ago" can only appear once at the end of an interval. SELECT INTERVAL '42 days 2 seconds ago ago'; ERROR: invalid input syntax for type interval: "42 days 2 seconds ago ago" @@ -1832,3 +2224,42 @@ SELECT INTERVAL '1 year months days 5 hours'; ERROR: invalid input syntax for type interval: "1 year months days 5 hours" LINE 1: SELECT INTERVAL '1 year months days 5 hours'; ^ +-- unacceptable reserved words in interval. Only "infinity", "+infinity" and +-- "-infinity" are allowed. +SELECT INTERVAL 'now'; +ERROR: invalid input syntax for type interval: "now" +LINE 1: SELECT INTERVAL 'now'; + ^ +SELECT INTERVAL 'today'; +ERROR: invalid input syntax for type interval: "today" +LINE 1: SELECT INTERVAL 'today'; + ^ +SELECT INTERVAL 'tomorrow'; +ERROR: invalid input syntax for type interval: "tomorrow" +LINE 1: SELECT INTERVAL 'tomorrow'; + ^ +SELECT INTERVAL 'allballs'; +ERROR: invalid input syntax for type interval: "allballs" +LINE 1: SELECT INTERVAL 'allballs'; + ^ +SELECT INTERVAL 'epoch'; +ERROR: invalid input syntax for type interval: "epoch" +LINE 1: SELECT INTERVAL 'epoch'; + ^ +SELECT INTERVAL 'yesterday'; +ERROR: invalid input syntax for type interval: "yesterday" +LINE 1: SELECT INTERVAL 'yesterday'; + ^ +-- infinity specification should be the only thing +SELECT INTERVAL 'infinity years'; +ERROR: invalid input syntax for type interval: "infinity years" +LINE 1: SELECT INTERVAL 'infinity years'; + ^ +SELECT INTERVAL 'infinity ago'; +ERROR: invalid input syntax for type interval: "infinity ago" +LINE 1: SELECT INTERVAL 'infinity ago'; + ^ +SELECT INTERVAL '+infinity -infinity'; +ERROR: invalid input syntax for type interval: "+infinity -infinity" +LINE 1: SELECT INTERVAL '+infinity -infinity'; + ^ diff --git a/src/test/regress/expected/timestamp.out b/src/test/regress/expected/timestamp.out index c64bcb7c12..835f0e5762 100644 --- a/src/test/regress/expected/timestamp.out +++ b/src/test/regress/expected/timestamp.out @@ -2125,3 +2125,65 @@ select * from generate_series('2020-01-01 00:00'::timestamp, '2020-01-02 03:00'::timestamp, '0 hour'::interval); ERROR: step size cannot equal zero +select generate_series(timestamp '1995-08-06 12:12:12', timestamp '1996-08-06 12:12:12', interval 'infinity'); +ERROR: step size cannot be infinite +select generate_series(timestamp '1995-08-06 12:12:12', timestamp '1996-08-06 12:12:12', interval '-infinity'); +ERROR: step size cannot be infinite +-- test arithmetic with infinite timestamps +select timestamp 'infinity' - timestamp 'infinity'; +ERROR: interval out of range +select timestamp 'infinity' - timestamp '-infinity'; + ?column? +---------- + infinity +(1 row) + +select timestamp '-infinity' - timestamp 'infinity'; + ?column? +----------- + -infinity +(1 row) + +select timestamp '-infinity' - timestamp '-infinity'; +ERROR: interval out of range +select timestamp 'infinity' - timestamp '1995-08-06 12:12:12'; + ?column? +---------- + infinity +(1 row) + +select timestamp '-infinity' - timestamp '1995-08-06 12:12:12'; + ?column? +----------- + -infinity +(1 row) + +-- test age() with infinite timestamps +select age(timestamp 'infinity'); + age +----------- + -infinity +(1 row) + +select age(timestamp '-infinity'); + age +---------- + infinity +(1 row) + +select age(timestamp 'infinity', timestamp 'infinity'); +ERROR: interval out of range +select age(timestamp 'infinity', timestamp '-infinity'); + age +---------- + infinity +(1 row) + +select age(timestamp '-infinity', timestamp 'infinity'); + age +----------- + -infinity +(1 row) + +select age(timestamp '-infinity', timestamp '-infinity'); +ERROR: interval out of range diff --git a/src/test/regress/expected/timestamptz.out b/src/test/regress/expected/timestamptz.out index 2ca2101dd4..a084357480 100644 --- a/src/test/regress/expected/timestamptz.out +++ b/src/test/regress/expected/timestamptz.out @@ -2468,6 +2468,10 @@ select * from generate_series('2020-01-01 00:00'::timestamptz, '2020-01-02 03:00'::timestamptz, '0 hour'::interval); ERROR: step size cannot equal zero +select generate_series(timestamptz '1995-08-06 12:12:12', timestamptz '1996-08-06 12:12:12', interval 'infinity'); +ERROR: step size cannot be infinite +select generate_series(timestamptz '1995-08-06 12:12:12', timestamptz '1996-08-06 12:12:12', interval '-infinity'); +ERROR: step size cannot be infinite -- Interval crossing time shift for Europe/Warsaw timezone (with DST) SET TimeZone to 'UTC'; SELECT date_add('2022-10-30 00:00:00+01'::timestamptz, @@ -3210,3 +3214,61 @@ select * from tmptz where f1 at time zone 'utc' = '2017-01-18 00:00'; Tue Jan 17 16:00:00 2017 PST (1 row) +-- test arithmetic with infinite timestamps +SELECT timestamptz 'infinity' - timestamptz 'infinity'; +ERROR: interval out of range +SELECT timestamptz 'infinity' - timestamptz '-infinity'; + ?column? +---------- + infinity +(1 row) + +SELECT timestamptz '-infinity' - timestamptz 'infinity'; + ?column? +----------- + -infinity +(1 row) + +SELECT timestamptz '-infinity' - timestamptz '-infinity'; +ERROR: interval out of range +SELECT timestamptz 'infinity' - timestamptz '1995-08-06 12:12:12'; + ?column? +---------- + infinity +(1 row) + +SELECT timestamptz '-infinity' - timestamptz '1995-08-06 12:12:12'; + ?column? +----------- + -infinity +(1 row) + +-- test age() with infinite timestamps +SELECT age(timestamptz 'infinity'); + age +----------- + -infinity +(1 row) + +SELECT age(timestamptz '-infinity'); + age +---------- + infinity +(1 row) + +SELECT age(timestamptz 'infinity', timestamptz 'infinity'); +ERROR: interval out of range +SELECT age(timestamptz 'infinity', timestamptz '-infinity'); + age +---------- + infinity +(1 row) + +SELECT age(timestamptz '-infinity', timestamptz 'infinity'); + age +----------- + -infinity +(1 row) + +SELECT age(timestamptz '-infinity', timestamptz '-infinity'); +ERROR: interval out of range diff --git a/src/test/regress/expected/window.out b/src/test/regress/expected/window.out index 69a38df10b..2201740c18 100644 --- a/src/test/regress/expected/window.out +++ b/src/test/regress/expected/window.out @@ -2372,6 +2372,7 @@ create temp table datetimes( f_timestamp timestamp ); insert into datetimes values +(0, '10:00', '10:00 BST', '-infinity', '-infinity', '-infinity'), (1, '11:00', '11:00 BST', '1 year', '2000-10-19 10:23:54+01', '2000-10-19 10:23:54'), (2, '12:00', '12:00 BST', '2 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'), (3, '13:00', '13:00 BST', '3 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'), @@ -2381,14 +2382,16 @@ insert into datetimes values (7, '17:00', '17:00 BST', '7 years', '2005-10-19 10:23:54+01', '2005-10-19 10:23:54'), (8, '18:00', '18:00 BST', '8 years', '2006-10-19 10:23:54+01', '2006-10-19 10:23:54'), (9, '19:00', '19:00 BST', '9 years', '2007-10-19 10:23:54+01', '2007-10-19 10:23:54'), -(10, '20:00', '20:00 BST', '10 years', '2008-10-19 10:23:54+01', '2008-10-19 10:23:54'); +(10, '20:00', '20:00 BST', '10 years', '2008-10-19 10:23:54+01', '2008-10-19 10:23:54'), +(11, '21:00', '21:00 BST', 'infinity', 'infinity', 'infinity'); select id, f_time, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_time range between '70 min'::interval preceding and '2 hours'::interval following); id | f_time | first_value | last_value ----+----------+-------------+------------ - 1 | 11:00:00 | 1 | 3 + 0 | 10:00:00 | 0 | 2 + 1 | 11:00:00 | 0 | 3 2 | 12:00:00 | 1 | 4 3 | 13:00:00 | 2 | 6 4 | 14:00:00 | 3 | 6 @@ -2396,9 +2399,10 @@ window w as (order by f_time range between 6 | 15:00:00 | 4 | 7 7 | 17:00:00 | 7 | 9 8 | 18:00:00 | 7 | 10 - 9 | 19:00:00 | 8 | 10 - 10 | 20:00:00 | 9 | 10 -(10 rows) + 9 | 19:00:00 | 8 | 11 + 10 | 20:00:00 | 9 | 11 + 11 | 21:00:00 | 10 | 11 +(12 rows) select id, f_time, first_value(id) over w, last_value(id) over w from datetimes @@ -2406,7 +2410,8 @@ window w as (order by f_time desc range between '70 min' preceding and '2 hours' following); id | f_time | first_value | last_value ----+----------+-------------+------------ - 10 | 20:00:00 | 10 | 8 + 11 | 21:00:00 | 11 | 9 + 10 | 20:00:00 | 11 | 8 9 | 19:00:00 | 10 | 7 8 | 18:00:00 | 9 | 7 7 | 17:00:00 | 8 | 5 @@ -2414,17 +2419,90 @@ window w as (order by f_time desc range between 5 | 15:00:00 | 6 | 3 4 | 14:00:00 | 6 | 2 3 | 13:00:00 | 4 | 1 - 2 | 12:00:00 | 3 | 1 - 1 | 11:00:00 | 2 | 1 -(10 rows) + 2 | 12:00:00 | 3 | 0 + 1 | 11:00:00 | 2 | 0 + 0 | 10:00:00 | 1 | 0 +(12 rows) +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time desc range between + '-70 min' preceding and '2 hours' following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval preceding and 'infinity'::interval following); + id | f_time | first_value | last_value +----+----------+-------------+------------ + 0 | 10:00:00 | 0 | 11 + 1 | 11:00:00 | 0 | 11 + 2 | 12:00:00 | 0 | 11 + 3 | 13:00:00 | 0 | 11 + 4 | 14:00:00 | 0 | 11 + 5 | 15:00:00 | 0 | 11 + 6 | 15:00:00 | 0 | 11 + 7 | 17:00:00 | 0 | 11 + 8 | 18:00:00 | 0 | 11 + 9 | 19:00:00 | 0 | 11 + 10 | 20:00:00 | 0 | 11 + 11 | 21:00:00 | 0 | 11 +(12 rows) + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + id | f_time | first_value | last_value +----+----------+-------------+------------ + 0 | 10:00:00 | | + 1 | 11:00:00 | | + 2 | 12:00:00 | | + 3 | 13:00:00 | | + 4 | 14:00:00 | | + 5 | 15:00:00 | | + 6 | 15:00:00 | | + 7 | 17:00:00 | | + 8 | 18:00:00 | | + 9 | 19:00:00 | | + 10 | 20:00:00 | | + 11 | 21:00:00 | | +(12 rows) + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval following and 'infinity'::interval following); + id | f_time | first_value | last_value +----+----------+-------------+------------ + 0 | 10:00:00 | | + 1 | 11:00:00 | | + 2 | 12:00:00 | | + 3 | 13:00:00 | | + 4 | 14:00:00 | | + 5 | 15:00:00 | | + 6 | 15:00:00 | | + 7 | 17:00:00 | | + 8 | 18:00:00 | | + 9 | 19:00:00 | | + 10 | 20:00:00 | | + 11 | 21:00:00 | | +(12 rows) + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function select id, f_timetz, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timetz range between '70 min'::interval preceding and '2 hours'::interval following); id | f_timetz | first_value | last_value ----+-------------+-------------+------------ - 1 | 11:00:00+01 | 1 | 3 + 0 | 10:00:00+01 | 0 | 2 + 1 | 11:00:00+01 | 0 | 3 2 | 12:00:00+01 | 1 | 4 3 | 13:00:00+01 | 2 | 6 4 | 14:00:00+01 | 3 | 6 @@ -2432,9 +2510,10 @@ window w as (order by f_timetz range between 6 | 15:00:00+01 | 4 | 7 7 | 17:00:00+01 | 7 | 9 8 | 18:00:00+01 | 7 | 10 - 9 | 19:00:00+01 | 8 | 10 - 10 | 20:00:00+01 | 9 | 10 -(10 rows) + 9 | 19:00:00+01 | 8 | 11 + 10 | 20:00:00+01 | 9 | 11 + 11 | 21:00:00+01 | 10 | 11 +(12 rows) select id, f_timetz, first_value(id) over w, last_value(id) over w from datetimes @@ -2442,7 +2521,8 @@ window w as (order by f_timetz desc range between '70 min' preceding and '2 hours' following); id | f_timetz | first_value | last_value ----+-------------+-------------+------------ - 10 | 20:00:00+01 | 10 | 8 + 11 | 21:00:00+01 | 11 | 9 + 10 | 20:00:00+01 | 11 | 8 9 | 19:00:00+01 | 10 | 7 8 | 18:00:00+01 | 9 | 7 7 | 17:00:00+01 | 8 | 5 @@ -2450,16 +2530,89 @@ window w as (order by f_timetz desc range between 5 | 15:00:00+01 | 6 | 3 4 | 14:00:00+01 | 6 | 2 3 | 13:00:00+01 | 4 | 1 - 2 | 12:00:00+01 | 3 | 1 - 1 | 11:00:00+01 | 2 | 1 -(10 rows) + 2 | 12:00:00+01 | 3 | 0 + 1 | 11:00:00+01 | 2 | 0 + 0 | 10:00:00+01 | 1 | 0 +(12 rows) +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz desc range between + '70 min' preceding and '-2 hours' following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval preceding and 'infinity'::interval following); + id | f_timetz | first_value | last_value +----+-------------+-------------+------------ + 0 | 10:00:00+01 | 0 | 11 + 1 | 11:00:00+01 | 0 | 11 + 2 | 12:00:00+01 | 0 | 11 + 3 | 13:00:00+01 | 0 | 11 + 4 | 14:00:00+01 | 0 | 11 + 5 | 15:00:00+01 | 0 | 11 + 6 | 15:00:00+01 | 0 | 11 + 7 | 17:00:00+01 | 0 | 11 + 8 | 18:00:00+01 | 0 | 11 + 9 | 19:00:00+01 | 0 | 11 + 10 | 20:00:00+01 | 0 | 11 + 11 | 21:00:00+01 | 0 | 11 +(12 rows) + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + id | f_timetz | first_value | last_value +----+-------------+-------------+------------ + 0 | 10:00:00+01 | | + 1 | 11:00:00+01 | | + 2 | 12:00:00+01 | | + 3 | 13:00:00+01 | | + 4 | 14:00:00+01 | | + 5 | 15:00:00+01 | | + 6 | 15:00:00+01 | | + 7 | 17:00:00+01 | | + 8 | 18:00:00+01 | | + 9 | 19:00:00+01 | | + 10 | 20:00:00+01 | | + 11 | 21:00:00+01 | | +(12 rows) + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval following and 'infinity'::interval following); + id | f_timetz | first_value | last_value +----+-------------+-------------+------------ + 0 | 10:00:00+01 | | + 1 | 11:00:00+01 | | + 2 | 12:00:00+01 | | + 3 | 13:00:00+01 | | + 4 | 14:00:00+01 | | + 5 | 15:00:00+01 | | + 6 | 15:00:00+01 | | + 7 | 17:00:00+01 | | + 8 | 18:00:00+01 | | + 9 | 19:00:00+01 | | + 10 | 20:00:00+01 | | + 11 | 21:00:00+01 | | +(12 rows) + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval following and + '-infinity'::interval following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function select id, f_interval, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_interval range between '1 year'::interval preceding and '1 year'::interval following); id | f_interval | first_value | last_value ----+------------+-------------+------------ + 0 | -infinity | 0 | 0 1 | @ 1 year | 1 | 2 2 | @ 2 years | 1 | 3 3 | @ 3 years | 2 | 4 @@ -2470,7 +2623,8 @@ window w as (order by f_interval range between 8 | @ 8 years | 7 | 9 9 | @ 9 years | 8 | 10 10 | @ 10 years | 9 | 10 -(10 rows) + 11 | infinity | 11 | 11 +(12 rows) select id, f_interval, first_value(id) over w, last_value(id) over w from datetimes @@ -2478,6 +2632,7 @@ window w as (order by f_interval desc range between '1 year' preceding and '1 year' following); id | f_interval | first_value | last_value ----+------------+-------------+------------ + 11 | infinity | 11 | 11 10 | @ 10 years | 10 | 9 9 | @ 9 years | 10 | 8 8 | @ 8 years | 9 | 7 @@ -2488,14 +2643,87 @@ window w as (order by f_interval desc range between 3 | @ 3 years | 4 | 2 2 | @ 2 years | 3 | 1 1 | @ 1 year | 2 | 1 -(10 rows) + 0 | -infinity | 0 | 0 +(12 rows) +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval desc range between + '-1 year' preceding and '1 year' following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval preceding and 'infinity'::interval following); + id | f_interval | first_value | last_value +----+------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | @ 1 year | 0 | 11 + 2 | @ 2 years | 0 | 11 + 3 | @ 3 years | 0 | 11 + 4 | @ 4 years | 0 | 11 + 5 | @ 5 years | 0 | 11 + 6 | @ 5 years | 0 | 11 + 7 | @ 7 years | 0 | 11 + 8 | @ 8 years | 0 | 11 + 9 | @ 9 years | 0 | 11 + 10 | @ 10 years | 0 | 11 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + id | f_interval | first_value | last_value +----+------------+-------------+------------ + 0 | -infinity | 0 | 0 + 1 | @ 1 year | 0 | 0 + 2 | @ 2 years | 0 | 0 + 3 | @ 3 years | 0 | 0 + 4 | @ 4 years | 0 | 0 + 5 | @ 5 years | 0 | 0 + 6 | @ 5 years | 0 | 0 + 7 | @ 7 years | 0 | 0 + 8 | @ 8 years | 0 | 0 + 9 | @ 9 years | 0 | 0 + 10 | @ 10 years | 0 | 0 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval following and 'infinity'::interval following); + id | f_interval | first_value | last_value +----+------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | @ 1 year | 11 | 11 + 2 | @ 2 years | 11 | 11 + 3 | @ 3 years | 11 | 11 + 4 | @ 4 years | 11 | 11 + 5 | @ 5 years | 11 | 11 + 6 | @ 5 years | 11 | 11 + 7 | @ 7 years | 11 | 11 + 8 | @ 8 years | 11 | 11 + 9 | @ 9 years | 11 | 11 + 10 | @ 10 years | 11 | 11 + 11 | infinity | 11 | 11 +(12 rows) + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function select id, f_timestamptz, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timestamptz range between '1 year'::interval preceding and '1 year'::interval following); id | f_timestamptz | first_value | last_value ----+------------------------------+-------------+------------ + 0 | -infinity | 0 | 0 1 | Thu Oct 19 02:23:54 2000 PDT | 1 | 3 2 | Fri Oct 19 02:23:54 2001 PDT | 1 | 4 3 | Fri Oct 19 02:23:54 2001 PDT | 1 | 4 @@ -2506,7 +2734,8 @@ window w as (order by f_timestamptz range between 8 | Thu Oct 19 02:23:54 2006 PDT | 7 | 9 9 | Fri Oct 19 02:23:54 2007 PDT | 8 | 10 10 | Sun Oct 19 02:23:54 2008 PDT | 9 | 10 -(10 rows) + 11 | infinity | 11 | 11 +(12 rows) select id, f_timestamptz, first_value(id) over w, last_value(id) over w from datetimes @@ -2514,6 +2743,7 @@ window w as (order by f_timestamptz desc range between '1 year' preceding and '1 year' following); id | f_timestamptz | first_value | last_value ----+------------------------------+-------------+------------ + 11 | infinity | 11 | 11 10 | Sun Oct 19 02:23:54 2008 PDT | 10 | 9 9 | Fri Oct 19 02:23:54 2007 PDT | 10 | 8 8 | Thu Oct 19 02:23:54 2006 PDT | 9 | 7 @@ -2524,14 +2754,87 @@ window w as (order by f_timestamptz desc range between 3 | Fri Oct 19 02:23:54 2001 PDT | 4 | 1 2 | Fri Oct 19 02:23:54 2001 PDT | 4 | 1 1 | Thu Oct 19 02:23:54 2000 PDT | 3 | 1 -(10 rows) + 0 | -infinity | 0 | 0 +(12 rows) +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz desc range between + '1 year' preceding and '-1 year' following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval preceding and 'infinity'::interval following); + id | f_timestamptz | first_value | last_value +----+------------------------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | Thu Oct 19 02:23:54 2000 PDT | 0 | 11 + 2 | Fri Oct 19 02:23:54 2001 PDT | 0 | 11 + 3 | Fri Oct 19 02:23:54 2001 PDT | 0 | 11 + 4 | Sat Oct 19 02:23:54 2002 PDT | 0 | 11 + 5 | Sun Oct 19 02:23:54 2003 PDT | 0 | 11 + 6 | Tue Oct 19 02:23:54 2004 PDT | 0 | 11 + 7 | Wed Oct 19 02:23:54 2005 PDT | 0 | 11 + 8 | Thu Oct 19 02:23:54 2006 PDT | 0 | 11 + 9 | Fri Oct 19 02:23:54 2007 PDT | 0 | 11 + 10 | Sun Oct 19 02:23:54 2008 PDT | 0 | 11 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + id | f_timestamptz | first_value | last_value +----+------------------------------+-------------+------------ + 0 | -infinity | 0 | 0 + 1 | Thu Oct 19 02:23:54 2000 PDT | 0 | 0 + 2 | Fri Oct 19 02:23:54 2001 PDT | 0 | 0 + 3 | Fri Oct 19 02:23:54 2001 PDT | 0 | 0 + 4 | Sat Oct 19 02:23:54 2002 PDT | 0 | 0 + 5 | Sun Oct 19 02:23:54 2003 PDT | 0 | 0 + 6 | Tue Oct 19 02:23:54 2004 PDT | 0 | 0 + 7 | Wed Oct 19 02:23:54 2005 PDT | 0 | 0 + 8 | Thu Oct 19 02:23:54 2006 PDT | 0 | 0 + 9 | Fri Oct 19 02:23:54 2007 PDT | 0 | 0 + 10 | Sun Oct 19 02:23:54 2008 PDT | 0 | 0 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval following and 'infinity'::interval following); + id | f_timestamptz | first_value | last_value +----+------------------------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | Thu Oct 19 02:23:54 2000 PDT | 11 | 11 + 2 | Fri Oct 19 02:23:54 2001 PDT | 11 | 11 + 3 | Fri Oct 19 02:23:54 2001 PDT | 11 | 11 + 4 | Sat Oct 19 02:23:54 2002 PDT | 11 | 11 + 5 | Sun Oct 19 02:23:54 2003 PDT | 11 | 11 + 6 | Tue Oct 19 02:23:54 2004 PDT | 11 | 11 + 7 | Wed Oct 19 02:23:54 2005 PDT | 11 | 11 + 8 | Thu Oct 19 02:23:54 2006 PDT | 11 | 11 + 9 | Fri Oct 19 02:23:54 2007 PDT | 11 | 11 + 10 | Sun Oct 19 02:23:54 2008 PDT | 11 | 11 + 11 | infinity | 11 | 11 +(12 rows) + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function select id, f_timestamp, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timestamp range between '1 year'::interval preceding and '1 year'::interval following); id | f_timestamp | first_value | last_value ----+--------------------------+-------------+------------ + 0 | -infinity | 0 | 0 1 | Thu Oct 19 10:23:54 2000 | 1 | 3 2 | Fri Oct 19 10:23:54 2001 | 1 | 4 3 | Fri Oct 19 10:23:54 2001 | 1 | 4 @@ -2542,7 +2845,8 @@ window w as (order by f_timestamp range between 8 | Thu Oct 19 10:23:54 2006 | 7 | 9 9 | Fri Oct 19 10:23:54 2007 | 8 | 10 10 | Sun Oct 19 10:23:54 2008 | 9 | 10 -(10 rows) + 11 | infinity | 11 | 11 +(12 rows) select id, f_timestamp, first_value(id) over w, last_value(id) over w from datetimes @@ -2550,6 +2854,7 @@ window w as (order by f_timestamp desc range between '1 year' preceding and '1 year' following); id | f_timestamp | first_value | last_value ----+--------------------------+-------------+------------ + 11 | infinity | 11 | 11 10 | Sun Oct 19 10:23:54 2008 | 10 | 9 9 | Fri Oct 19 10:23:54 2007 | 10 | 8 8 | Thu Oct 19 10:23:54 2006 | 9 | 7 @@ -2560,8 +2865,80 @@ window w as (order by f_timestamp desc range between 3 | Fri Oct 19 10:23:54 2001 | 4 | 1 2 | Fri Oct 19 10:23:54 2001 | 4 | 1 1 | Thu Oct 19 10:23:54 2000 | 3 | 1 -(10 rows) + 0 | -infinity | 0 | 0 +(12 rows) +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp desc range between + '-1 year' preceding and '1 year' following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval preceding and 'infinity'::interval following); + id | f_timestamp | first_value | last_value +----+--------------------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | Thu Oct 19 10:23:54 2000 | 0 | 11 + 2 | Fri Oct 19 10:23:54 2001 | 0 | 11 + 3 | Fri Oct 19 10:23:54 2001 | 0 | 11 + 4 | Sat Oct 19 10:23:54 2002 | 0 | 11 + 5 | Sun Oct 19 10:23:54 2003 | 0 | 11 + 6 | Tue Oct 19 10:23:54 2004 | 0 | 11 + 7 | Wed Oct 19 10:23:54 2005 | 0 | 11 + 8 | Thu Oct 19 10:23:54 2006 | 0 | 11 + 9 | Fri Oct 19 10:23:54 2007 | 0 | 11 + 10 | Sun Oct 19 10:23:54 2008 | 0 | 11 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + id | f_timestamp | first_value | last_value +----+--------------------------+-------------+------------ + 0 | -infinity | 0 | 0 + 1 | Thu Oct 19 10:23:54 2000 | 0 | 0 + 2 | Fri Oct 19 10:23:54 2001 | 0 | 0 + 3 | Fri Oct 19 10:23:54 2001 | 0 | 0 + 4 | Sat Oct 19 10:23:54 2002 | 0 | 0 + 5 | Sun Oct 19 10:23:54 2003 | 0 | 0 + 6 | Tue Oct 19 10:23:54 2004 | 0 | 0 + 7 | Wed Oct 19 10:23:54 2005 | 0 | 0 + 8 | Thu Oct 19 10:23:54 2006 | 0 | 0 + 9 | Fri Oct 19 10:23:54 2007 | 0 | 0 + 10 | Sun Oct 19 10:23:54 2008 | 0 | 0 + 11 | infinity | 0 | 11 +(12 rows) + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval following and 'infinity'::interval following); + id | f_timestamp | first_value | last_value +----+--------------------------+-------------+------------ + 0 | -infinity | 0 | 11 + 1 | Thu Oct 19 10:23:54 2000 | 11 | 11 + 2 | Fri Oct 19 10:23:54 2001 | 11 | 11 + 3 | Fri Oct 19 10:23:54 2001 | 11 | 11 + 4 | Sat Oct 19 10:23:54 2002 | 11 | 11 + 5 | Sun Oct 19 10:23:54 2003 | 11 | 11 + 6 | Tue Oct 19 10:23:54 2004 | 11 | 11 + 7 | Wed Oct 19 10:23:54 2005 | 11 | 11 + 8 | Thu Oct 19 10:23:54 2006 | 11 | 11 + 9 | Fri Oct 19 10:23:54 2007 | 11 | 11 + 10 | Sun Oct 19 10:23:54 2008 | 11 | 11 + 11 | infinity | 11 | 11 +(12 rows) + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed +ERROR: invalid preceding or following size in window function -- RANGE offset PRECEDING/FOLLOWING error cases select sum(salary) over (order by enroll_date, salary range between '1 year'::interval preceding and '2 years'::interval following exclude ties), salary, enroll_date from empsalary; @@ -4375,6 +4752,52 @@ SELECT i,AVG(v::interval) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDE 4 | (4 rows) +-- moving aggregates over infinite intervals +SELECT x + ,avg(x) OVER(ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING ) as curr_next_avg + ,avg(x) OVER(ROWS BETWEEN 1 PRECEDING AND CURRENT ROW ) as prev_curr_avg + ,sum(x) OVER(ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING ) as curr_next_sum + ,sum(x) OVER(ROWS BETWEEN 1 PRECEDING AND CURRENT ROW ) as prev_curr_sum +FROM (VALUES (NULL::interval), + ('infinity'::interval), + ('-2147483648 days -2147483648 months -9223372036854775807 usecs'), -- extreme interval value + ('-infinity'::interval), + ('2147483647 days 2147483647 months 9223372036854775806 usecs'), -- extreme interval value + ('infinity'::interval), + ('6 days'::interval), + ('7 days'::interval), + (NULL::interval), + ('-infinity'::interval)) v(x); + x | curr_next_avg | prev_curr_avg | curr_next_sum | prev_curr_sum +------------------------------------------------------------------------------+-------------------+-------------------+---------------+--------------- + | infinity | | infinity | + infinity | infinity | infinity | infinity | infinity + @ 178956970 years 8 mons 2147483648 days 2562047788 hours 54.775807 secs ago | -infinity | infinity | -infinity | infinity + -infinity | -infinity | -infinity | -infinity | -infinity + @ 178956970 years 7 mons 2147483647 days 2562047788 hours 54.775806 secs | infinity | -infinity | infinity | -infinity + infinity | infinity | infinity | infinity | infinity + @ 6 days | @ 6 days 12 hours | infinity | @ 13 days | infinity + @ 7 days | @ 7 days | @ 6 days 12 hours | @ 7 days | @ 13 days + | -infinity | @ 7 days | -infinity | @ 7 days + -infinity | -infinity | -infinity | -infinity | -infinity +(10 rows) + +--should fail. +SELECT x, avg(x) OVER(ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) +FROM (VALUES (NULL::interval), + ('3 days'::interval), + ('infinity'::timestamptz - now()), + ('6 days'::interval), + ('-infinity'::interval)) v(x); +ERROR: interval out of range. +--should fail. +SELECT x, sum(x) OVER(ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) +FROM (VALUES (NULL::interval), + ('3 days'::interval), + ('infinity'::timestamptz - now()), + ('6 days'::interval), + ('-infinity'::interval)) v(x); +ERROR: interval out of range. SELECT i,SUM(v::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v); i | sum diff --git a/src/test/regress/sql/brin_multi.sql b/src/test/regress/sql/brin_multi.sql index b666dbad67..116106d30f 100644 --- a/src/test/regress/sql/brin_multi.sql +++ b/src/test/regress/sql/brin_multi.sql @@ -682,6 +682,25 @@ SELECT * FROM brin_interval_test WHERE a = '-30 years'::interval; EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF) SELECT * FROM brin_interval_test WHERE a = '30 years'::interval; +DROP TABLE brin_interval_test; +RESET enable_seqscan; + +-- test handling of infinite interval values +CREATE TABLE brin_interval_test(a INTERVAL); + +INSERT INTO brin_interval_test VALUES ('-infinity'), ('infinity'); +INSERT INTO brin_interval_test SELECT (i || ' days')::interval FROM generate_series(100, 140) s(i); + +CREATE INDEX ON brin_interval_test USING brin (a interval_minmax_multi_ops) WITH (pages_per_range=1); + +SET enable_seqscan = off; + +EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF) +SELECT * FROM brin_interval_test WHERE a = '-30 years'::interval; + +EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF) +SELECT * FROM brin_interval_test WHERE a = '30 years'::interval; + DROP TABLE brin_interval_test; RESET enable_seqscan; RESET datestyle; diff --git a/src/test/regress/sql/horology.sql b/src/test/regress/sql/horology.sql index 39a35a6b7c..252bce4b1c 100644 --- a/src/test/regress/sql/horology.sql +++ b/src/test/regress/sql/horology.sql @@ -213,10 +213,12 @@ SELECT t.d1 AS t, i.f1 AS i, t.d1 + i.f1 AS "add", t.d1 - i.f1 AS "subtract" SELECT t.f1 AS t, i.f1 AS i, t.f1 + i.f1 AS "add", t.f1 - i.f1 AS "subtract" FROM TIME_TBL t, INTERVAL_TBL i + WHERE isfinite(i.f1) ORDER BY 1,2; SELECT t.f1 AS t, i.f1 AS i, t.f1 + i.f1 AS "add", t.f1 - i.f1 AS "subtract" FROM TIMETZ_TBL t, INTERVAL_TBL i + WHERE isfinite(i.f1) ORDER BY 1,2; -- SQL9x OVERLAPS operator @@ -293,7 +295,6 @@ SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 + t.f1 AS plus SELECT d.f1 AS "timestamp", t.f1 AS "interval", d.f1 - t.f1 AS minus FROM TEMP_TIMESTAMP d, INTERVAL_TBL t - WHERE isfinite(d.f1) ORDER BY minus, "timestamp", "interval"; SELECT d.f1 AS "timestamp", diff --git a/src/test/regress/sql/interval.sql b/src/test/regress/sql/interval.sql index a0a373f08b..caad291890 100644 --- a/src/test/regress/sql/interval.sql +++ b/src/test/regress/sql/interval.sql @@ -14,6 +14,8 @@ SELECT INTERVAL '-1 days +02:03' AS "22 hours ago..."; SELECT INTERVAL '1.5 weeks' AS "Ten days twelve hours"; SELECT INTERVAL '1.5 months' AS "One month 15 days"; SELECT INTERVAL '10 years -11 month -12 days +13:14' AS "9 years..."; +SELECT INTERVAL 'infinity' AS "eternity"; +SELECT INTERVAL '-infinity' AS "beginning of time"; CREATE TABLE INTERVAL_TBL (f1 interval); @@ -27,6 +29,8 @@ INSERT INTO INTERVAL_TBL (f1) VALUES ('1 day 2 hours 3 minutes 4 seconds'); INSERT INTO INTERVAL_TBL (f1) VALUES ('6 years'); INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months'); INSERT INTO INTERVAL_TBL (f1) VALUES ('5 months 12 hours'); +INSERT INTO INTERVAL_TBL (f1) VALUES ('infinity'); +INSERT INTO INTERVAL_TBL (f1) VALUES ('-infinity'); -- badly formatted interval INSERT INTO INTERVAL_TBL (f1) VALUES ('badly formatted interval'); @@ -66,6 +70,17 @@ SELECT r1.*, r2.* WHERE r1.f1 > r2.f1 ORDER BY r1.f1, r2.f1; +-- test unary minus + +SELECT f1, -f1 FROM INTERVAL_TBL; +SELECT -('-2147483648 months'::interval); -- should fail +SELECT -('-2147483647 months'::interval); -- ok +SELECT -('-2147483648 days'::interval); -- should fail +SELECT -('-2147483647 days'::interval); -- ok +SELECT -('-9223372036854775808 us'::interval); -- should fail +SELECT -('-9223372036854775807 us'::interval); -- ok +SELECT -('-2147483647 months -2147483647 days -9223372036854775807 us'::interval); -- should fail + -- Test intervals that are large enough to overflow 64 bits in comparisons CREATE TEMP TABLE INTERVAL_TBL_OF (f1 interval); INSERT INTO INTERVAL_TBL_OF (f1) VALUES @@ -95,6 +110,9 @@ SELECT f1 FROM INTERVAL_TBL_OF r1 ORDER BY f1; SELECT f1 FROM INTERVAL_TBL_OF r1 ORDER BY f1; RESET enable_seqscan; +-- subtracting about-to-overflow values should result in 0 +SELECT f1 - f1 FROM INTERVAL_TBL_OF; + DROP TABLE INTERVAL_TBL_OF; -- Test multiplication and division with intervals. @@ -140,7 +158,7 @@ SELECT * FROM INTERVAL_TBL; -- known to change the allowed input syntax for type interval without -- updating pg_aggregate.agginitval -select avg(f1) from interval_tbl; +select avg(f1) from interval_tbl where isfinite(f1); -- test long interval input select '4 millenniums 5 centuries 4 decades 1 year 4 months 4 days 17 minutes 31 seconds'::interval; @@ -528,13 +546,13 @@ select make_interval(mins := -1, secs := -9223372036800.0); -- test that INT_MIN number is formatted properly SET IntervalStyle to postgres; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; SET IntervalStyle to sql_standard; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; SET IntervalStyle to iso_8601; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; SET IntervalStyle to postgres_verbose; -select interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +select interval '-2147483647 months -2147483648 days -9223372036854775808 us'; -- check that '30 days' equals '1 month' according to the hash function select '30 days'::interval = '1 month'::interval as t; @@ -598,6 +616,157 @@ SELECT f1, -- internal overflow test case SELECT extract(epoch from interval '1000000000 days'); +-- +-- test infinite intervals +-- + +-- largest finite intervals +SELECT interval '-2147483648 months -2147483648 days -9223372036854775807 us'; +SELECT interval '2147483647 months 2147483647 days 9223372036854775806 us'; + +-- infinite intervals +SELECT interval '-2147483648 months -2147483648 days -9223372036854775808 us'; +SELECT interval '2147483647 months 2147483647 days 9223372036854775807 us'; + +CREATE TABLE INFINITE_INTERVAL_TBL (i interval); +INSERT INTO INFINITE_INTERVAL_TBL VALUES ('infinity'), ('-infinity'), ('1 year 2 days 3 hours'); + +SELECT i, isfinite(i) FROM INFINITE_INTERVAL_TBL; + +-- test basic arithmetic +CREATE FUNCTION eval(expr text) +RETURNS text AS +$$ +DECLARE + result text; +BEGIN + EXECUTE 'select '||expr INTO result; + RETURN result; +EXCEPTION WHEN OTHERS THEN + RETURN SQLERRM; +END +$$ +LANGUAGE plpgsql; + +SELECT d AS date, i AS interval, + eval(format('date %L + interval %L', d, i)) AS plus, + eval(format('date %L - interval %L', d, i)) AS minus +FROM (VALUES (date '-infinity'), + (date '1995-08-06'), + (date 'infinity')) AS t1(d), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + +SELECT i1 AS interval1, i2 AS interval2, + eval(format('interval %L + interval %L', i1, i2)) AS plus, + eval(format('interval %L - interval %L', i1, i2)) AS minus +FROM (VALUES (interval '-infinity'), + (interval '2 months'), + (interval 'infinity')) AS t1(i1), + (VALUES (interval '-infinity'), + (interval '10 days'), + (interval 'infinity')) AS t2(i2); + +SELECT interval '2147483646 months 2147483646 days 9223372036854775806 us' + interval '1 month 1 day 1 us'; +SELECT interval '-2147483647 months -2147483647 days -9223372036854775807 us' + interval '-1 month -1 day -1 us'; +SELECT interval '2147483646 months 2147483646 days 9223372036854775806 us' - interval '-1 month -1 day -1 us'; +SELECT interval '-2147483647 months -2147483647 days -9223372036854775807 us' - interval '1 month 1 day 1 us'; + +SELECT t AS timestamp, i AS interval, + eval(format('timestamp %L + interval %L', t, i)) AS plus, + eval(format('timestamp %L - interval %L', t, i)) AS minus +FROM (VALUES (timestamp '-infinity'), + (timestamp '1995-08-06 12:30:15'), + (timestamp 'infinity')) AS t1(t), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + +SELECT t AT TIME ZONE 'GMT' AS timestamptz, i AS interval, + eval(format('timestamptz %L + interval %L', t, i)) AS plus, + eval(format('timestamptz %L - interval %L', t, i)) AS minus +FROM (VALUES (timestamptz '-infinity'), + (timestamptz '1995-08-06 12:30:15 GMT'), + (timestamptz 'infinity')) AS t1(t), + (VALUES (interval '-infinity'), + (interval 'infinity')) AS t2(i); + +-- time +/- infinite interval not supported +SELECT time '11:27:42' + interval 'infinity'; +SELECT time '11:27:42' + interval '-infinity'; +SELECT time '11:27:42' - interval 'infinity'; +SELECT time '11:27:42' - interval '-infinity'; +SELECT timetz '11:27:42' + interval 'infinity'; +SELECT timetz '11:27:42' + interval '-infinity'; +SELECT timetz '11:27:42' - interval 'infinity'; +SELECT timetz '11:27:42' - interval '-infinity'; + +SELECT lhst.i lhs, + rhst.i rhs, + lhst.i < rhst.i AS lt, + lhst.i <= rhst.i AS le, + lhst.i = rhst.i AS eq, + lhst.i > rhst.i AS gt, + lhst.i >= rhst.i AS ge, + lhst.i <> rhst.i AS ne + FROM INFINITE_INTERVAL_TBL lhst CROSS JOIN INFINITE_INTERVAL_TBL rhst + WHERE NOT isfinite(lhst.i); + +SELECT i AS interval, + -i AS um, + i * 2.0 AS mul, + i * -2.0 AS mul_neg, + i * 'infinity' AS mul_inf, + i * '-infinity' AS mul_inf_neg, + i / 3.0 AS div, + i / -3.0 AS div_neg + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + +SELECT -interval '-2147483647 months -2147483647 days -9223372036854775807 us'; +SELECT interval 'infinity' * 'nan'; +SELECT interval '-infinity' * 'nan'; +SELECT interval '-1073741824 months -1073741824 days -4611686018427387904 us' * 2; +SELECT interval 'infinity' * 0; +SELECT interval '-infinity' * 0; +SELECT interval '0 days' * 'infinity'::float; +SELECT interval '0 days' * '-infinity'::float; +SELECT interval '5 days' * 'infinity'::float; +SELECT interval '5 days' * '-infinity'::float; + +SELECT interval 'infinity' / 'infinity'; +SELECT interval 'infinity' / '-infinity'; +SELECT interval 'infinity' / 'nan'; +SELECT interval '-infinity' / 'infinity'; +SELECT interval '-infinity' / '-infinity'; +SELECT interval '-infinity' / 'nan'; +SELECT interval '-1073741824 months -1073741824 days -4611686018427387904 us' / 0.5; + +SELECT date_bin('infinity', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00'); +SELECT date_bin('-infinity', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00'); + +SELECT i AS interval, date_trunc('hour', i) + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + +SELECT i AS interval, justify_days(i), justify_hours(i), justify_interval(i) + FROM INFINITE_INTERVAL_TBL + WHERE NOT isfinite(i); + +SELECT timezone('infinity'::interval, '1995-08-06 12:12:12'::timestamp); +SELECT timezone('-infinity'::interval, '1995-08-06 12:12:12'::timestamp); +SELECT timezone('infinity'::interval, '1995-08-06 12:12:12'::timestamptz); +SELECT timezone('-infinity'::interval, '1995-08-06 12:12:12'::timestamptz); +SELECT timezone('infinity'::interval, '12:12:12'::time); +SELECT timezone('-infinity'::interval, '12:12:12'::time); +SELECT timezone('infinity'::interval, '12:12:12'::timetz); +SELECT timezone('-infinity'::interval, '12:12:12'::timetz); + +SELECT 'infinity'::interval::time; +SELECT '-infinity'::interval::time; + +SELECT to_char('infinity'::interval, 'YYYY'); +SELECT to_char('-infinity'::interval, 'YYYY'); + -- "ago" can only appear once at the end of an interval. SELECT INTERVAL '42 days 2 seconds ago ago'; SELECT INTERVAL '2 minutes ago 5 days'; @@ -605,3 +774,17 @@ SELECT INTERVAL '2 minutes ago 5 days'; -- consecutive and dangling units are not allowed. SELECT INTERVAL 'hour 5 months'; SELECT INTERVAL '1 year months days 5 hours'; + +-- unacceptable reserved words in interval. Only "infinity", "+infinity" and +-- "-infinity" are allowed. +SELECT INTERVAL 'now'; +SELECT INTERVAL 'today'; +SELECT INTERVAL 'tomorrow'; +SELECT INTERVAL 'allballs'; +SELECT INTERVAL 'epoch'; +SELECT INTERVAL 'yesterday'; + +-- infinity specification should be the only thing +SELECT INTERVAL 'infinity years'; +SELECT INTERVAL 'infinity ago'; +SELECT INTERVAL '+infinity -infinity'; diff --git a/src/test/regress/sql/timestamp.sql b/src/test/regress/sql/timestamp.sql index b9bcce9cfe..ea12ffd18d 100644 --- a/src/test/regress/sql/timestamp.sql +++ b/src/test/regress/sql/timestamp.sql @@ -397,3 +397,22 @@ select generate_series('2022-01-01 00:00'::timestamp, select * from generate_series('2020-01-01 00:00'::timestamp, '2020-01-02 03:00'::timestamp, '0 hour'::interval); +select generate_series(timestamp '1995-08-06 12:12:12', timestamp '1996-08-06 12:12:12', interval 'infinity'); +select generate_series(timestamp '1995-08-06 12:12:12', timestamp '1996-08-06 12:12:12', interval '-infinity'); + + +-- test arithmetic with infinite timestamps +select timestamp 'infinity' - timestamp 'infinity'; +select timestamp 'infinity' - timestamp '-infinity'; +select timestamp '-infinity' - timestamp 'infinity'; +select timestamp '-infinity' - timestamp '-infinity'; +select timestamp 'infinity' - timestamp '1995-08-06 12:12:12'; +select timestamp '-infinity' - timestamp '1995-08-06 12:12:12'; + +-- test age() with infinite timestamps +select age(timestamp 'infinity'); +select age(timestamp '-infinity'); +select age(timestamp 'infinity', timestamp 'infinity'); +select age(timestamp 'infinity', timestamp '-infinity'); +select age(timestamp '-infinity', timestamp 'infinity'); +select age(timestamp '-infinity', timestamp '-infinity'); diff --git a/src/test/regress/sql/timestamptz.sql b/src/test/regress/sql/timestamptz.sql index cdc57bc160..a2dcd5f5d8 100644 --- a/src/test/regress/sql/timestamptz.sql +++ b/src/test/regress/sql/timestamptz.sql @@ -458,6 +458,8 @@ select generate_series('2022-01-01 00:00'::timestamptz, select * from generate_series('2020-01-01 00:00'::timestamptz, '2020-01-02 03:00'::timestamptz, '0 hour'::interval); +select generate_series(timestamptz '1995-08-06 12:12:12', timestamptz '1996-08-06 12:12:12', interval 'infinity'); +select generate_series(timestamptz '1995-08-06 12:12:12', timestamptz '1996-08-06 12:12:12', interval '-infinity'); -- Interval crossing time shift for Europe/Warsaw timezone (with DST) SET TimeZone to 'UTC'; @@ -642,3 +644,19 @@ insert into tmptz values ('2017-01-18 00:00+00'); explain (costs off) select * from tmptz where f1 at time zone 'utc' = '2017-01-18 00:00'; select * from tmptz where f1 at time zone 'utc' = '2017-01-18 00:00'; + +-- test arithmetic with infinite timestamps +SELECT timestamptz 'infinity' - timestamptz 'infinity'; +SELECT timestamptz 'infinity' - timestamptz '-infinity'; +SELECT timestamptz '-infinity' - timestamptz 'infinity'; +SELECT timestamptz '-infinity' - timestamptz '-infinity'; +SELECT timestamptz 'infinity' - timestamptz '1995-08-06 12:12:12'; +SELECT timestamptz '-infinity' - timestamptz '1995-08-06 12:12:12'; + +-- test age() with infinite timestamps +SELECT age(timestamptz 'infinity'); +SELECT age(timestamptz '-infinity'); +SELECT age(timestamptz 'infinity', timestamptz 'infinity'); +SELECT age(timestamptz 'infinity', timestamptz '-infinity'); +SELECT age(timestamptz '-infinity', timestamptz 'infinity'); +SELECT age(timestamptz '-infinity', timestamptz '-infinity'); diff --git a/src/test/regress/sql/window.sql b/src/test/regress/sql/window.sql index 9113a92ae0..437e948d6c 100644 --- a/src/test/regress/sql/window.sql +++ b/src/test/regress/sql/window.sql @@ -673,6 +673,7 @@ create temp table datetimes( ); insert into datetimes values +(0, '10:00', '10:00 BST', '-infinity', '-infinity', '-infinity'), (1, '11:00', '11:00 BST', '1 year', '2000-10-19 10:23:54+01', '2000-10-19 10:23:54'), (2, '12:00', '12:00 BST', '2 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'), (3, '13:00', '13:00 BST', '3 years', '2001-10-19 10:23:54+01', '2001-10-19 10:23:54'), @@ -682,7 +683,8 @@ insert into datetimes values (7, '17:00', '17:00 BST', '7 years', '2005-10-19 10:23:54+01', '2005-10-19 10:23:54'), (8, '18:00', '18:00 BST', '8 years', '2006-10-19 10:23:54+01', '2006-10-19 10:23:54'), (9, '19:00', '19:00 BST', '9 years', '2007-10-19 10:23:54+01', '2007-10-19 10:23:54'), -(10, '20:00', '20:00 BST', '10 years', '2008-10-19 10:23:54+01', '2008-10-19 10:23:54'); +(10, '20:00', '20:00 BST', '10 years', '2008-10-19 10:23:54+01', '2008-10-19 10:23:54'), +(11, '21:00', '21:00 BST', 'infinity', 'infinity', 'infinity'); select id, f_time, first_value(id) over w, last_value(id) over w from datetimes @@ -694,6 +696,32 @@ from datetimes window w as (order by f_time desc range between '70 min' preceding and '2 hours' following); +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time desc range between + '-70 min' preceding and '2 hours' following); -- error, negative offset disallowed + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval preceding and 'infinity'::interval following); + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + 'infinity'::interval following and 'infinity'::interval following); + +select id, f_time, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_time range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed + select id, f_timetz, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timetz range between @@ -704,6 +732,32 @@ from datetimes window w as (order by f_timetz desc range between '70 min' preceding and '2 hours' following); +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz desc range between + '70 min' preceding and '-2 hours' following); -- error, negative offset disallowed + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval preceding and 'infinity'::interval following); + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval following and 'infinity'::interval following); + +select id, f_timetz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timetz range between + 'infinity'::interval following and + '-infinity'::interval following); -- error, negative offset disallowed + select id, f_interval, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_interval range between @@ -714,6 +768,32 @@ from datetimes window w as (order by f_interval desc range between '1 year' preceding and '1 year' following); +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval desc range between + '-1 year' preceding and '1 year' following); -- error, negative offset disallowed + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval preceding and 'infinity'::interval following); + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + 'infinity'::interval following and 'infinity'::interval following); + +select id, f_interval, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_interval range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed + select id, f_timestamptz, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timestamptz range between @@ -724,6 +804,32 @@ from datetimes window w as (order by f_timestamptz desc range between '1 year' preceding and '1 year' following); +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz desc range between + '1 year' preceding and '-1 year' following); -- error, negative offset disallowed + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval preceding and 'infinity'::interval following); + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + 'infinity'::interval following and 'infinity'::interval following); + +select id, f_timestamptz, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamptz range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed + select id, f_timestamp, first_value(id) over w, last_value(id) over w from datetimes window w as (order by f_timestamp range between @@ -734,6 +840,32 @@ from datetimes window w as (order by f_timestamp desc range between '1 year' preceding and '1 year' following); +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp desc range between + '-1 year' preceding and '1 year' following); -- error, negative offset disallowed + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval preceding and 'infinity'::interval following); + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval preceding and 'infinity'::interval preceding); + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + 'infinity'::interval following and 'infinity'::interval following); + +select id, f_timestamp, first_value(id) over w, last_value(id) over w +from datetimes +window w as (order by f_timestamp range between + '-infinity'::interval following and + 'infinity'::interval following); -- error, negative offset disallowed + -- RANGE offset PRECEDING/FOLLOWING error cases select sum(salary) over (order by enroll_date, salary range between '1 year'::interval preceding and '2 years'::interval following exclude ties), salary, enroll_date from empsalary; @@ -1591,6 +1723,39 @@ SELECT i,AVG(v::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED SELECT i,AVG(v::interval) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) FROM (VALUES(1,'1 sec'),(2,'2 sec'),(3,NULL),(4,NULL)) t(i,v); +-- moving aggregates over infinite intervals +SELECT x + ,avg(x) OVER(ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING ) as curr_next_avg + ,avg(x) OVER(ROWS BETWEEN 1 PRECEDING AND CURRENT ROW ) as prev_curr_avg + ,sum(x) OVER(ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING ) as curr_next_sum + ,sum(x) OVER(ROWS BETWEEN 1 PRECEDING AND CURRENT ROW ) as prev_curr_sum +FROM (VALUES (NULL::interval), + ('infinity'::interval), + ('-2147483648 days -2147483648 months -9223372036854775807 usecs'), -- extreme interval value + ('-infinity'::interval), + ('2147483647 days 2147483647 months 9223372036854775806 usecs'), -- extreme interval value + ('infinity'::interval), + ('6 days'::interval), + ('7 days'::interval), + (NULL::interval), + ('-infinity'::interval)) v(x); + +--should fail. +SELECT x, avg(x) OVER(ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) +FROM (VALUES (NULL::interval), + ('3 days'::interval), + ('infinity'::timestamptz - now()), + ('6 days'::interval), + ('-infinity'::interval)) v(x); + +--should fail. +SELECT x, sum(x) OVER(ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) +FROM (VALUES (NULL::interval), + ('3 days'::interval), + ('infinity'::timestamptz - now()), + ('6 days'::interval), + ('-infinity'::interval)) v(x); + SELECT i,SUM(v::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v); diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 92c0003ab1..dba3498a13 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -1205,6 +1205,7 @@ IntegerSet InternalDefaultACL InternalGrant Interval +IntervalAggState IntoClause InvalMessageArray InvalidationMsgsGroup