Commit 9d229f39 authored by Tom Lane's avatar Tom Lane

Provide moving-aggregate support for a bunch of numerical aggregates.

First installment of the promised moving-aggregate support in built-in
aggregates: count(), sum(), avg(), stddev() and variance() for
assorted datatypes, though not for float4/float8.

In passing, remove a 2001-vintage kluge in interval_accum(): interval
array elements have been properly aligned since around 2003, but
nobody remembered to take out this workaround.  Also, fix a thinko
in the opr_sanity tests for moving-aggregate catalog entries.

David Rowley and Florian Pflug, reviewed by Dean Rasheed
parent a9d9acbf
......@@ -717,13 +717,58 @@ int8inc(PG_FUNCTION_ARGS)
}
}
Datum
int8dec(PG_FUNCTION_ARGS)
{
/*
* When int8 is pass-by-reference, we provide this special case to avoid
* palloc overhead for COUNT(): when called as an aggregate, we know that
* the argument is modifiable local storage, so just update it in-place.
* (If int8 is pass-by-value, then of course this is useless as well as
* incorrect, so just ifdef it out.)
*/
#ifndef USE_FLOAT8_BYVAL /* controls int8 too */
if (AggCheckCallContext(fcinfo, NULL))
{
int64 *arg = (int64 *) PG_GETARG_POINTER(0);
int64 result;
result = *arg - 1;
/* Overflow check */
if (result > 0 && *arg < 0)
ereport(ERROR,
(errcode(ERRCODE_NUMERIC_VALUE_OUT_OF_RANGE),
errmsg("bigint out of range")));
*arg = result;
PG_RETURN_POINTER(arg);
}
else
#endif
{
/* Not called as an aggregate, so just do it the dumb way */
int64 arg = PG_GETARG_INT64(0);
int64 result;
result = arg - 1;
/* Overflow check */
if (result > 0 && arg < 0)
ereport(ERROR,
(errcode(ERRCODE_NUMERIC_VALUE_OUT_OF_RANGE),
errmsg("bigint out of range")));
PG_RETURN_INT64(result);
}
}
/*
* These functions are exactly like int8inc but are used for aggregates that
* count only non-null values. Since the functions are declared strict,
* the null checks happen before we ever get here, and all we need do is
* increment the state value. We could actually make these pg_proc entries
* point right at int8inc, but then the opr_sanity regression test would
* complain about mismatched entries for a built-in function.
* These functions are exactly like int8inc/int8dec but are used for
* aggregates that count only non-null values. Since the functions are
* declared strict, the null checks happen before we ever get here, and all we
* need do is increment the state value. We could actually make these pg_proc
* entries point right at int8inc/int8dec, but then the opr_sanity regression
* test would complain about mismatched entries for a built-in function.
*/
Datum
......@@ -738,6 +783,12 @@ int8inc_float8_float8(PG_FUNCTION_ARGS)
return int8inc(fcinfo);
}
Datum
int8dec_any(PG_FUNCTION_ARGS)
{
return int8dec(fcinfo);
}
Datum
int8larger(PG_FUNCTION_ARGS)
......
This diff is collapsed.
......@@ -3229,7 +3229,6 @@ interval_mi(PG_FUNCTION_ARGS)
(errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE),
errmsg("interval out of range")));
PG_RETURN_INTERVAL_P(result);
}
......@@ -3376,12 +3375,18 @@ interval_div(PG_FUNCTION_ARGS)
}
/*
* interval_accum and interval_avg implement the AVG(interval) aggregate.
* interval_accum, interval_accum_inv, and interval_avg implement the
* AVG(interval) aggregate.
*
* 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.
*
* NOTE: The inverse transition function cannot guarantee exact results
* when using float8 timestamps. However, int8 timestamps are now the
* norm, and the probable range of values is not so wide that disastrous
* cancellation is likely even with float8, so we'll ignore the risk.
*/
Datum
......@@ -3402,17 +3407,8 @@ interval_accum(PG_FUNCTION_ARGS)
if (ndatums != 2)
elog(ERROR, "expected 2-element interval array");
/*
* XXX memcpy, instead of just extracting a pointer, to work around buggy
* array code: it won't ensure proper alignment of Interval objects on
* machines where double requires 8-byte alignment. That should be fixed,
* but in the meantime...
*
* Note: must use DatumGetPointer here, not DatumGetIntervalP, else some
* compilers optimize into double-aligned load/store anyway.
*/
memcpy((void *) &sumX, DatumGetPointer(transdatums[0]), sizeof(Interval));
memcpy((void *) &N, DatumGetPointer(transdatums[1]), sizeof(Interval));
sumX = *(DatumGetIntervalP(transdatums[0]));
N = *(DatumGetIntervalP(transdatums[1]));
newsum = DatumGetIntervalP(DirectFunctionCall2(interval_pl,
IntervalPGetDatum(&sumX),
......@@ -3428,6 +3424,41 @@ interval_accum(PG_FUNCTION_ARGS)
PG_RETURN_ARRAYTYPE_P(result);
}
Datum
interval_accum_inv(PG_FUNCTION_ARGS)
{
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;
deconstruct_array(transarray,
INTERVALOID, sizeof(Interval), false, 'd',
&transdatums, NULL, &ndatums);
if (ndatums != 2)
elog(ERROR, "expected 2-element interval array");
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, 'd');
PG_RETURN_ARRAYTYPE_P(result);
}
Datum
interval_avg(PG_FUNCTION_ARGS)
{
......@@ -3443,17 +3474,8 @@ interval_avg(PG_FUNCTION_ARGS)
if (ndatums != 2)
elog(ERROR, "expected 2-element interval array");
/*
* XXX memcpy, instead of just extracting a pointer, to work around buggy
* array code: it won't ensure proper alignment of Interval objects on
* machines where double requires 8-byte alignment. That should be fixed,
* but in the meantime...
*
* Note: must use DatumGetPointer here, not DatumGetIntervalP, else some
* compilers optimize into double-aligned load/store anyway.
*/
memcpy((void *) &sumX, DatumGetPointer(transdatums[0]), sizeof(Interval));
memcpy((void *) &N, DatumGetPointer(transdatums[1]), sizeof(Interval));
sumX = *(DatumGetIntervalP(transdatums[0]));
N = *(DatumGetIntervalP(transdatums[1]));
/* SQL defines AVG of no values to be NULL */
if (N.time == 0)
......@@ -3461,7 +3483,7 @@ interval_avg(PG_FUNCTION_ARGS)
return DirectFunctionCall2(interval_div,
IntervalPGetDatum(&sumX),
Float8GetDatum(N.time));
Float8GetDatum((double) N.time));
}
......
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201404121
#define CATALOG_VERSION_NO 201404122
#endif
This diff is collapsed.
......@@ -1311,8 +1311,12 @@ DESCR("truncate interval to specified units");
DATA(insert OID = 1219 ( int8inc PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 20 "20" _null_ _null_ _null_ _null_ int8inc _null_ _null_ _null_ ));
DESCR("increment");
DATA(insert OID = 3546 ( int8dec PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 20 "20" _null_ _null_ _null_ _null_ int8dec _null_ _null_ _null_ ));
DESCR("decrement");
DATA(insert OID = 2804 ( int8inc_any PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 20 "20 2276" _null_ _null_ _null_ _null_ int8inc_any _null_ _null_ _null_ ));
DESCR("increment, ignores second argument");
DATA(insert OID = 3547 ( int8dec_any PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 20 "20 2276" _null_ _null_ _null_ _null_ int8dec_any _null_ _null_ _null_ ));
DESCR("decrement, ignores second argument");
DATA(insert OID = 1230 ( int8abs PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 20 "20" _null_ _null_ _null_ _null_ int8abs _null_ _null_ _null_ ));
DATA(insert OID = 1236 ( int8larger PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 20 "20 20" _null_ _null_ _null_ _null_ int8larger _null_ _null_ _null_ ));
......@@ -2423,6 +2427,8 @@ DATA(insert OID = 1833 ( numeric_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i
DESCR("aggregate transition function");
DATA(insert OID = 2858 ( numeric_avg_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 1700" _null_ _null_ _null_ _null_ numeric_avg_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3548 ( numeric_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 1700" _null_ _null_ _null_ _null_ numeric_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 1834 ( int2_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 21" _null_ _null_ _null_ _null_ int2_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 1835 ( int4_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 23" _null_ _null_ _null_ _null_ int4_accum _null_ _null_ _null_ ));
......@@ -2431,6 +2437,12 @@ DATA(insert OID = 1836 ( int8_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0
DESCR("aggregate transition function");
DATA(insert OID = 2746 ( int8_avg_accum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 20" _null_ _null_ _null_ _null_ int8_avg_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3567 ( int2_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 21" _null_ _null_ _null_ _null_ int2_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3568 ( int4_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 23" _null_ _null_ _null_ _null_ int4_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3569 ( int8_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0 2281 "2281 20" _null_ _null_ _null_ _null_ int8_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3178 ( numeric_sum PGNSP PGUID 12 1 0 0 0 f f f f f f i 1 0 1700 "2281" _null_ _null_ _null_ _null_ numeric_sum _null_ _null_ _null_ ));
DESCR("aggregate final function");
DATA(insert OID = 1837 ( numeric_avg PGNSP PGUID 12 1 0 0 0 f f f f f f i 1 0 1700 "2281" _null_ _null_ _null_ _null_ numeric_avg _null_ _null_ _null_ ));
......@@ -2451,14 +2463,22 @@ DATA(insert OID = 1842 ( int8_sum PGNSP PGUID 12 1 0 0 0 f f f f f f i 2 0
DESCR("aggregate transition function");
DATA(insert OID = 1843 ( interval_accum PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1187 "1187 1186" _null_ _null_ _null_ _null_ interval_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3549 ( interval_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1187 "1187 1186" _null_ _null_ _null_ _null_ interval_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 1844 ( interval_avg PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 1186 "1187" _null_ _null_ _null_ _null_ interval_avg _null_ _null_ _null_ ));
DESCR("aggregate final function");
DATA(insert OID = 1962 ( int2_avg_accum PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1016 "1016 21" _null_ _null_ _null_ _null_ int2_avg_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 1963 ( int4_avg_accum PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1016 "1016 23" _null_ _null_ _null_ _null_ int4_avg_accum _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3570 ( int2_avg_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1016 "1016 21" _null_ _null_ _null_ _null_ int2_avg_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 3571 ( int4_avg_accum_inv PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 1016 "1016 23" _null_ _null_ _null_ _null_ int4_avg_accum_inv _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 1964 ( int8_avg PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 1700 "1016" _null_ _null_ _null_ _null_ int8_avg _null_ _null_ _null_ ));
DESCR("aggregate final function");
DATA(insert OID = 3572 ( int2int4_sum PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 20 "1016" _null_ _null_ _null_ _null_ int2int4_sum _null_ _null_ _null_ ));
DESCR("aggregate final function");
DATA(insert OID = 2805 ( int8inc_float8_float8 PGNSP PGUID 12 1 0 0 0 f f f f t f i 3 0 20 "20 701 701" _null_ _null_ _null_ _null_ int8inc_float8_float8 _null_ _null_ _null_ ));
DESCR("aggregate transition function");
DATA(insert OID = 2806 ( float8_regr_accum PGNSP PGUID 12 1 0 0 0 f f f f t f i 3 0 1022 "1022 701 701" _null_ _null_ _null_ _null_ float8_regr_accum _null_ _null_ _null_ ));
......
......@@ -1005,9 +1005,13 @@ extern Datum float4_numeric(PG_FUNCTION_ARGS);
extern Datum numeric_float4(PG_FUNCTION_ARGS);
extern Datum numeric_accum(PG_FUNCTION_ARGS);
extern Datum numeric_avg_accum(PG_FUNCTION_ARGS);
extern Datum numeric_accum_inv(PG_FUNCTION_ARGS);
extern Datum int2_accum(PG_FUNCTION_ARGS);
extern Datum int4_accum(PG_FUNCTION_ARGS);
extern Datum int8_accum(PG_FUNCTION_ARGS);
extern Datum int2_accum_inv(PG_FUNCTION_ARGS);
extern Datum int4_accum_inv(PG_FUNCTION_ARGS);
extern Datum int8_accum_inv(PG_FUNCTION_ARGS);
extern Datum int8_avg_accum(PG_FUNCTION_ARGS);
extern Datum numeric_avg(PG_FUNCTION_ARGS);
extern Datum numeric_sum(PG_FUNCTION_ARGS);
......@@ -1020,7 +1024,10 @@ extern Datum int4_sum(PG_FUNCTION_ARGS);
extern Datum int8_sum(PG_FUNCTION_ARGS);
extern Datum int2_avg_accum(PG_FUNCTION_ARGS);
extern Datum int4_avg_accum(PG_FUNCTION_ARGS);
extern Datum int2_avg_accum_inv(PG_FUNCTION_ARGS);
extern Datum int4_avg_accum_inv(PG_FUNCTION_ARGS);
extern Datum int8_avg(PG_FUNCTION_ARGS);
extern Datum int2int4_sum(PG_FUNCTION_ARGS);
extern Datum width_bucket_numeric(PG_FUNCTION_ARGS);
extern Datum hash_numeric(PG_FUNCTION_ARGS);
......
......@@ -74,8 +74,10 @@ extern Datum int8div(PG_FUNCTION_ARGS);
extern Datum int8abs(PG_FUNCTION_ARGS);
extern Datum int8mod(PG_FUNCTION_ARGS);
extern Datum int8inc(PG_FUNCTION_ARGS);
extern Datum int8dec(PG_FUNCTION_ARGS);
extern Datum int8inc_any(PG_FUNCTION_ARGS);
extern Datum int8inc_float8_float8(PG_FUNCTION_ARGS);
extern Datum int8dec_any(PG_FUNCTION_ARGS);
extern Datum int8larger(PG_FUNCTION_ARGS);
extern Datum int8smaller(PG_FUNCTION_ARGS);
......
......@@ -184,6 +184,7 @@ extern Datum interval_mul(PG_FUNCTION_ARGS);
extern Datum mul_d_interval(PG_FUNCTION_ARGS);
extern Datum interval_div(PG_FUNCTION_ARGS);
extern Datum interval_accum(PG_FUNCTION_ARGS);
extern Datum interval_accum_inv(PG_FUNCTION_ARGS);
extern Datum interval_avg(PG_FUNCTION_ARGS);
extern Datum timestamp_mi(PG_FUNCTION_ARGS);
......
......@@ -936,13 +936,13 @@ WHERE a.aggfnoid = p.oid AND
----------+---------+-----+---------
(0 rows)
-- transfn and mtransfn should have same strictness setting.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, mptr.oid, mptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS mptr
-- mtransfn and minvtransfn should have same strictness setting.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, iptr.oid, iptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS iptr
WHERE a.aggfnoid = p.oid AND
a.aggtransfn = ptr.oid AND
a.aggmtransfn = mptr.oid AND
ptr.proisstrict != mptr.proisstrict;
a.aggmtransfn = ptr.oid AND
a.aggminvtransfn = iptr.oid AND
ptr.proisstrict != iptr.proisstrict;
aggfnoid | proname | oid | proname | oid | proname
----------+---------+-----+---------+-----+---------
(0 rows)
......
This diff is collapsed.
......@@ -760,14 +760,14 @@ WHERE a.aggfnoid = p.oid AND
a.aggminitval IS NULL AND
NOT binary_coercible(p.proargtypes[0], a.aggmtranstype);
-- transfn and mtransfn should have same strictness setting.
-- mtransfn and minvtransfn should have same strictness setting.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, mptr.oid, mptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS mptr
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, iptr.oid, iptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS iptr
WHERE a.aggfnoid = p.oid AND
a.aggtransfn = ptr.oid AND
a.aggmtransfn = mptr.oid AND
ptr.proisstrict != mptr.proisstrict;
a.aggmtransfn = ptr.oid AND
a.aggminvtransfn = iptr.oid AND
ptr.proisstrict != iptr.proisstrict;
-- Cross-check aggsortop (if present) against pg_operator.
-- We expect to find entries for bool_and, bool_or, every, max, and min.
......
......@@ -476,3 +476,144 @@ JOIN sum_following ON sum_following.i = vs.i
WINDOW fwd AS (
ORDER BY vs.i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
);
--
-- Test various built-in aggregates that have moving-aggregate support
--
-- test inverse transition functions handle NULLs properly
SELECT i,AVG(v::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,AVG(v::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,AVG(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);
SELECT i,AVG(v::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1.5),(2,2.5),(3,NULL),(4,NULL)) t(i,v);
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);
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);
SELECT i,SUM(v::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,SUM(v::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,SUM(v::money) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,'1.10'),(2,'2.20'),(3,NULL),(4,NULL)) t(i,v);
SELECT i,SUM(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);
SELECT i,SUM(v::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1.1),(2,2.2),(3,NULL),(4,NULL)) t(i,v);
SELECT SUM(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1.01),(2,2),(3,3)) v(i,n);
SELECT i,COUNT(v) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,COUNT(*) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT VAR_POP(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_POP(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_POP(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_POP(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_SAMP(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_SAMP(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_SAMP(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VAR_SAMP(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VARIANCE(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VARIANCE(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VARIANCE(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT VARIANCE(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT STDDEV_POP(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_POP(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_POP(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_POP(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_SAMP(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_SAMP(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_SAMP(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV_SAMP(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(1,NULL),(2,600),(3,470),(4,170),(5,430),(6,300)) r(i,n);
SELECT STDDEV(n::bigint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(0,NULL),(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT STDDEV(n::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(0,NULL),(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT STDDEV(n::smallint) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(0,NULL),(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
SELECT STDDEV(n::numeric) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
FROM (VALUES(0,NULL),(1,600),(2,470),(3,170),(4,430),(5,300)) r(i,n);
-- test that inverse transition functions work with various frame options
SELECT i,SUM(v::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND CURRENT ROW)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,SUM(v::int) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,NULL),(4,NULL)) t(i,v);
SELECT i,SUM(v::int) OVER (ORDER BY i ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
FROM (VALUES(1,1),(2,2),(3,3),(4,4)) t(i,v);
-- ensure aggregate over numeric properly recovers from NaN values
SELECT a, b,
SUM(b) OVER(ORDER BY A ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
FROM (VALUES(1,1::numeric),(2,2),(3,'NaN'),(4,3),(5,4)) t(a,b);
-- It might be tempting for someone to add an inverse trans function for
-- float and double precision. This should not be done as it can give incorrect
-- results. This test should fail if anyone ever does this without thinking too
-- hard about it.
SELECT to_char(SUM(n::float8) OVER (ORDER BY i ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING),'999999999999999999999D9')
FROM (VALUES(1,1e20),(2,1)) n(i,n);
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment