Commit a9d9acbf authored by Tom Lane's avatar Tom Lane

Create infrastructure for moving-aggregate optimization.

Until now, when executing an aggregate function as a window function
within a window with moving frame start (that is, any frame start mode
except UNBOUNDED PRECEDING), we had to recalculate the aggregate from
scratch each time the frame head moved.  This patch allows an aggregate
definition to include an alternate "moving aggregate" implementation
that includes an inverse transition function for removing rows from
the aggregate's running state.  As long as this can be done successfully,
runtime is proportional to the total number of input rows, rather than
to the number of input rows times the average frame length.

This commit includes the core infrastructure, documentation, and regression
tests using user-defined aggregates.  Follow-on commits will update some
of the built-in aggregates to use this feature.

David Rowley and Florian Pflug, reviewed by Dean Rasheed; additional
hacking by me
parent 3c41b812
......@@ -386,6 +386,24 @@
<entry><literal><link linkend="catalog-pg-proc"><structname>pg_proc</structname></link>.oid</literal></entry>
<entry>Final function (zero if none)</entry>
</row>
<row>
<entry><structfield>aggmtransfn</structfield></entry>
<entry><type>regproc</type></entry>
<entry><literal><link linkend="catalog-pg-proc"><structname>pg_proc</structname></link>.oid</literal></entry>
<entry>Forward transition function for moving-aggregate mode (zero if none)</entry>
</row>
<row>
<entry><structfield>aggminvtransfn</structfield></entry>
<entry><type>regproc</type></entry>
<entry><literal><link linkend="catalog-pg-proc"><structname>pg_proc</structname></link>.oid</literal></entry>
<entry>Inverse transition function for moving-aggregate mode (zero if none)</entry>
</row>
<row>
<entry><structfield>aggmfinalfn</structfield></entry>
<entry><type>regproc</type></entry>
<entry><literal><link linkend="catalog-pg-proc"><structname>pg_proc</structname></link>.oid</literal></entry>
<entry>Final function for moving-aggregate mode (zero if none)</entry>
</row>
<row>
<entry><structfield>aggsortop</structfield></entry>
<entry><type>oid</type></entry>
......@@ -405,6 +423,20 @@
<entry>Approximate average size (in bytes) of the transition state
data, or zero to use a default estimate</entry>
</row>
<row>
<entry><structfield>aggmtranstype</structfield></entry>
<entry><type>oid</type></entry>
<entry><literal><link linkend="catalog-pg-type"><structname>pg_type</structname></link>.oid</literal></entry>
<entry>Data type of the aggregate function's internal transition (state)
data for moving-aggregate mode (zero if none)</entry>
</row>
<row>
<entry><structfield>aggmtransspace</structfield></entry>
<entry><type>int4</type></entry>
<entry></entry>
<entry>Approximate average size (in bytes) of the transition state data
for moving-aggregate mode, or zero to use a default estimate</entry>
</row>
<row>
<entry><structfield>agginitval</structfield></entry>
<entry><type>text</type></entry>
......@@ -416,6 +448,17 @@
value starts out null.
</entry>
</row>
<row>
<entry><structfield>aggminitval</structfield></entry>
<entry><type>text</type></entry>
<entry></entry>
<entry>
The initial value of the transition state for moving-aggregate mode.
This is a text field containing the initial value in its external
string representation. If this field is null, the transition state
value starts out null.
</entry>
</row>
</tbody>
</tgroup>
</table>
......
This diff is collapsed.
......@@ -131,6 +131,161 @@ CREATE AGGREGATE avg (float8)
</para>
</note>
<para>
Aggregate function calls in SQL allow <literal>DISTINCT</>
and <literal>ORDER BY</> options that control which rows are fed
to the aggregate's transition function and in what order. These
options are implemented behind the scenes and are not the concern
of the aggregate's support functions.
</para>
<para>
For further details see the
<xref linkend="sql-createaggregate">
command.
</para>
<sect2 id="xaggr-moving-aggregates">
<title>Moving-Aggregate Mode</title>
<indexterm>
<primary>moving-aggregate mode</primary>
</indexterm>
<indexterm>
<primary>aggregate function</primary>
<secondary>moving aggregate</secondary>
</indexterm>
<para>
Aggregate functions can optionally support <firstterm>moving-aggregate
mode</>, which allows substantially faster execution of aggregate
functions within windows with moving frame starting points.
(See <xref linkend="tutorial-window">
and <xref linkend="syntax-window-functions"> for information about use of
aggregate functions as window functions.)
The basic idea is that in addition to a normal <quote>forward</>
transition function, the aggregate provides an <firstterm>inverse
transition function</>, which allows rows to be removed from the
aggregate's running state value when they exit the window frame.
For example a <function>sum</> aggregate, which uses addition as the
forward transition function, would use subtraction as the inverse
transition function. Without an inverse transition function, the window
function mechanism must recalculate the aggregate from scratch each time
the frame starting point moves, resulting in run time proportional to the
number of input rows times the average frame length. With an inverse
transition function, the run time is only proportional to the number of
input rows.
</para>
<para>
The inverse transition function is passed the current state value and the
aggregate input value(s) for the earliest row included in the current
state. It must reconstruct what the state value would have been if the
given input value had never been aggregated, but only the rows following
it. This sometimes requires that the forward transition function keep
more state than is needed for plain aggregation mode. Therefore, the
moving-aggregate mode uses a completely separate implementation from the
plain mode: it has its own state data type, its own forward transition
function, and its own final function if needed. These can be the same as
the plain mode's data type and functions, if there is no need for extra
state.
</para>
<para>
As an example, we could extend the <function>sum</> aggregate given above
to support moving-aggregate mode like this:
<programlisting>
CREATE AGGREGATE sum (complex)
(
sfunc = complex_add,
stype = complex,
initcond = '(0,0)',
msfunc = complex_add,
minvfunc = complex_sub,
mstype = complex,
minitcond = '(0,0)'
);
</programlisting>
The parameters whose names begin with <literal>m</> define the
moving-aggregate implementation. Except for the inverse transition
function <literal>minvfunc</>, they correspond to the plain-aggregate
parameters without <literal>m</>.
</para>
<para>
The forward transition function for moving-aggregate mode is not allowed
to return NULL as the new state value. If the inverse transition
function returns NULL, this is taken as an indication that the inverse
function cannot reverse the state calculation for this particular input,
and so the aggregate calculation will be redone from scratch for the
current frame starting position. This convention allows moving-aggregate
mode to be used in situations where there are some infrequent cases that
are impractical to reverse out of the running state value. The inverse
transition function can <quote>punt</> on these cases, and yet still come
out ahead so long as it can work for most cases. As an example, an
aggregate working with floating-point numbers might choose to punt when
a <literal>NaN</> (not a number) input has to be removed from the running
state value.
</para>
<para>
When writing moving-aggregate support functions, it is important to be
sure that the inverse transition function can reconstruct the correct
state value exactly. Otherwise there might be user-visible differences
in results depending on whether the moving-aggregate mode is used.
An example of an aggregate for which adding an inverse transition
function seems easy at first, yet where this requirement cannot be met
is <function>sum</> over <type>float4</> or <type>float8</> inputs. A
naive declaration of <function>sum(<type>float8</>)</function> could be
<programlisting>
CREATE AGGREGATE unsafe_sum (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi
);
</programlisting>
This aggregate, however, can give wildly different results than it would
have without the inverse transition function. For example, consider
<programlisting>
SELECT
unsafe_sum(x) OVER (ORDER BY n ROWS BETWEEN CURRENT ROW AND 1 FOLLOWING)
FROM (VALUES (1, 1.0e20::float8),
(2, 1.0::float8)) AS v (n,x);
</programlisting>
This query returns <literal>0</> as its second result, rather than the
expected answer of <literal>1</>. The cause is the limited precision of
floating-point values: adding <literal>1</> to <literal>1e20</> results
in <literal>1e20</> again, and so subtracting <literal>1e20</> from that
yields <literal>0</>, not <literal>1</>. Note that this is a limitation
of floating-point arithmetic in general, not a limitation
of <productname>PostgreSQL</>.
</para>
</sect2>
<sect2 id="xaggr-polymorphic-aggregates">
<title>Polymorphic and Variadic Aggregates</title>
<indexterm>
<primary>aggregate function</primary>
<secondary>polymorphic</secondary>
</indexterm>
<indexterm>
<primary>aggregate function</primary>
<secondary>variadic</secondary>
</indexterm>
<para>
Aggregate functions can use polymorphic
state transition functions or final functions, so that the same functions
......@@ -189,8 +344,8 @@ SELECT attrelid::regclass, array_accum(atttypid::regtype)
by declaring its last argument as a <literal>VARIADIC</> array, in much
the same fashion as for regular functions; see
<xref linkend="xfunc-sql-variadic-functions">. The aggregate's transition
function must have the same array type as its last argument. The
transition function typically would also be marked <literal>VARIADIC</>,
function(s) must have the same array type as their last argument. The
transition function(s) typically would also be marked <literal>VARIADIC</>,
but this is not strictly required.
</para>
......@@ -220,13 +375,15 @@ SELECT myaggregate(a, b, c ORDER BY a) FROM ...
</para>
</note>
<para>
Aggregate function calls in SQL allow <literal>DISTINCT</>
and <literal>ORDER BY</> options that control which rows are fed
to the aggregate's transition function and in what order. These
options are implemented behind the scenes and are not the concern
of the aggregate's support functions.
</para>
</sect2>
<sect2 id="xaggr-ordered-set-aggregates">
<title>Ordered-Set Aggregates</title>
<indexterm>
<primary>aggregate function</primary>
<secondary>ordered set</secondary>
</indexterm>
<para>
The aggregates we have been describing so far are <quote>normal</>
......@@ -311,6 +468,21 @@ SELECT percentile_disc(0.5) WITHIN GROUP (ORDER BY income) FROM households;
returns anyelement</>.
</para>
<para>
Currently, ordered-set aggregates cannot be used as window functions,
and therefore there is no need for them to support moving-aggregate mode.
</para>
</sect2>
<sect2 id="xaggr-support-functions">
<title>Support Functions for Aggregates</title>
<indexterm>
<primary>aggregate function</primary>
<secondary>support functions for</secondary>
</indexterm>
<para>
A function written in C can detect that it is being called as an
aggregate transition or final function by calling
......@@ -341,9 +513,6 @@ if (AggCheckCallContext(fcinfo, NULL))
source code.
</para>
<para>
For further details see the
<xref linkend="sql-createaggregate">
command.
</para>
</sect2>
</sect1>
This diff is collapsed.
......@@ -61,11 +61,17 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
char aggKind = AGGKIND_NORMAL;
List *transfuncName = NIL;
List *finalfuncName = NIL;
List *mtransfuncName = NIL;
List *minvtransfuncName = NIL;
List *mfinalfuncName = NIL;
List *sortoperatorName = NIL;
TypeName *baseType = NULL;
TypeName *transType = NULL;
TypeName *mtransType = NULL;
int32 transSpace = 0;
int32 mtransSpace = 0;
char *initval = NULL;
char *minitval = NULL;
int numArgs;
int numDirectArgs = 0;
oidvector *parameterTypes;
......@@ -75,7 +81,9 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
List *parameterDefaults;
Oid variadicArgType;
Oid transTypeId;
Oid mtransTypeId = InvalidOid;
char transTypeType;
char mtransTypeType = 0;
ListCell *pl;
/* Convert list of names to a name and namespace */
......@@ -114,6 +122,12 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
transfuncName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "finalfunc") == 0)
finalfuncName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "msfunc") == 0)
mtransfuncName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "minvfunc") == 0)
minvtransfuncName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "mfinalfunc") == 0)
mfinalfuncName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "sortop") == 0)
sortoperatorName = defGetQualifiedName(defel);
else if (pg_strcasecmp(defel->defname, "basetype") == 0)
......@@ -135,10 +149,16 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
transType = defGetTypeName(defel);
else if (pg_strcasecmp(defel->defname, "sspace") == 0)
transSpace = defGetInt32(defel);
else if (pg_strcasecmp(defel->defname, "mstype") == 0)
mtransType = defGetTypeName(defel);
else if (pg_strcasecmp(defel->defname, "msspace") == 0)
mtransSpace = defGetInt32(defel);
else if (pg_strcasecmp(defel->defname, "initcond") == 0)
initval = defGetString(defel);
else if (pg_strcasecmp(defel->defname, "initcond1") == 0)
initval = defGetString(defel);
else if (pg_strcasecmp(defel->defname, "minitcond") == 0)
minitval = defGetString(defel);
else
ereport(WARNING,
(errcode(ERRCODE_SYNTAX_ERROR),
......@@ -158,6 +178,46 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate sfunc must be specified")));
/*
* if mtransType is given, mtransfuncName and minvtransfuncName must be as
* well; if not, then none of the moving-aggregate options should have
* been given.
*/
if (mtransType != NULL)
{
if (mtransfuncName == NIL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate msfunc must be specified when mstype is specified")));
if (minvtransfuncName == NIL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate minvfunc must be specified when mstype is specified")));
}
else
{
if (mtransfuncName != NIL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate msfunc must not be specified without mstype")));
if (minvtransfuncName != NIL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate minvfunc must not be specified without mstype")));
if (mfinalfuncName != NIL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate mfinalfunc must not be specified without mstype")));
if (mtransSpace != 0)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate msspace must not be specified without mstype")));
if (minitval != NULL)
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate minitcond must not be specified without mstype")));
}
/*
* look up the aggregate's input datatype(s).
*/
......@@ -250,6 +310,27 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
format_type_be(transTypeId))));
}
/*
* If a moving-aggregate transtype is specified, look that up. Same
* restrictions as for transtype.
*/
if (mtransType)
{
mtransTypeId = typenameTypeId(NULL, mtransType);
mtransTypeType = get_typtype(mtransTypeId);
if (mtransTypeType == TYPTYPE_PSEUDO &&
!IsPolymorphicType(mtransTypeId))
{
if (mtransTypeId == INTERNALOID && superuser())
/* okay */ ;
else
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("aggregate transition data type cannot be %s",
format_type_be(mtransTypeId))));
}
}
/*
* If we have an initval, and it's not for a pseudotype (particularly a
* polymorphic type), make sure it's acceptable to the type's input
......@@ -268,6 +349,18 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
(void) OidInputFunctionCall(typinput, initval, typioparam, -1);
}
/*
* Likewise for moving-aggregate initval.
*/
if (minitval && mtransTypeType != TYPTYPE_PSEUDO)
{
Oid typinput,
typioparam;
getTypeInputInfo(mtransTypeId, &typinput, &typioparam);
(void) OidInputFunctionCall(typinput, minitval, typioparam, -1);
}
/*
* Most of the argument-checking is done inside of AggregateCreate
*/
......@@ -284,8 +377,14 @@ DefineAggregate(List *name, List *args, bool oldstyle, List *parameters,
variadicArgType,
transfuncName, /* step function name */
finalfuncName, /* final function name */
mtransfuncName, /* fwd trans function name */
minvtransfuncName, /* inv trans function name */
mfinalfuncName, /* final function name */
sortoperatorName, /* sort operator name */
transTypeId, /* transition data type */
transSpace, /* transition space */
initval); /* initial condition */
mtransTypeId, /* transition data type */
mtransSpace, /* transition space */
initval, /* initial condition */
minitval); /* initial condition */
}
......@@ -1798,8 +1798,10 @@ ExecInitAgg(Agg *node, EState *estate, int eflags)
aggref->aggtype,
aggref->inputcollid,
transfn_oid,
InvalidOid, /* invtrans is not needed here */
finalfn_oid,
&transfnexpr,
NULL,
&finalfnexpr);
/* set up infrastructure for calling the transfn and finalfn */
......@@ -1847,7 +1849,8 @@ ExecInitAgg(Agg *node, EState *estate, int eflags)
* type and transtype are the same (or at least binary-compatible), so
* that it's OK to use the first aggregated input value as the initial
* transValue. This should have been checked at agg definition time,
* but just in case...
* but we must check again in case the transfn's strictness property
* has been changed.
*/
if (peraggstate->transfn.fn_strict && peraggstate->initValueIsNull)
{
......@@ -2126,6 +2129,12 @@ ExecReScanAgg(AggState *node)
ExecReScan(node->ss.ps.lefttree);
}
/***********************************************************************
* API exposed to aggregate functions
***********************************************************************/
/*
* AggCheckCallContext - test if a SQL function is being called as an aggregate
*
......@@ -2152,7 +2161,7 @@ AggCheckCallContext(FunctionCallInfo fcinfo, MemoryContext *aggcontext)
if (fcinfo->context && IsA(fcinfo->context, WindowAggState))
{
if (aggcontext)
*aggcontext = ((WindowAggState *) fcinfo->context)->aggcontext;
*aggcontext = ((WindowAggState *) fcinfo->context)->curaggcontext;
return AGG_CONTEXT_WINDOW;
}
......
This diff is collapsed.
......@@ -471,7 +471,11 @@ count_agg_clauses_walker(Node *node, count_agg_clauses_context *context)
Assert(aggref->agglevelsup == 0);
/* fetch info about aggregate from pg_aggregate */
/*
* Fetch info about aggregate from pg_aggregate. Note it's correct to
* ignore the moving-aggregate variant, since what we're concerned
* with here is aggregates not window functions.
*/
aggTuple = SearchSysCache1(AGGFNOID,
ObjectIdGetDatum(aggref->aggfnoid));
if (!HeapTupleIsValid(aggTuple))
......
......@@ -1187,11 +1187,13 @@ resolve_aggregate_transtype(Oid aggfuncid,
* For an ordered-set aggregate, remember that agg_input_types describes
* the direct arguments followed by the aggregated arguments.
*
* transfn_oid and finalfn_oid identify the funcs to be called; the latter
* may be InvalidOid.
* transfn_oid, invtransfn_oid and finalfn_oid identify the funcs to be
* called; the latter two may be InvalidOid.
*
* Pointers to the constructed trees are returned into *transfnexpr and
* *finalfnexpr. The latter is set to NULL if there's no finalfn.
* Pointers to the constructed trees are returned into *transfnexpr,
* *invtransfnexpr and *finalfnexpr. If there is no invtransfn or finalfn,
* the respective pointers are set to NULL. Since use of the invtransfn is
* optional, NULL may be passed for invtransfnexpr.
*/
void
build_aggregate_fnexprs(Oid *agg_input_types,
......@@ -1203,8 +1205,10 @@ build_aggregate_fnexprs(Oid *agg_input_types,
Oid agg_result_type,
Oid agg_input_collation,
Oid transfn_oid,
Oid invtransfn_oid,
Oid finalfn_oid,
Expr **transfnexpr,
Expr **invtransfnexpr,
Expr **finalfnexpr)
{
Param *argp;
......@@ -1249,6 +1253,26 @@ build_aggregate_fnexprs(Oid *agg_input_types,
fexpr->funcvariadic = agg_variadic;
*transfnexpr = (Expr *) fexpr;
/*
* Build invtransfn expression if requested, with same args as transfn
*/
if (invtransfnexpr != NULL)
{
if (OidIsValid(invtransfn_oid))
{
fexpr = makeFuncExpr(invtransfn_oid,
agg_state_type,
args,
InvalidOid,
agg_input_collation,
COERCE_EXPLICIT_CALL);
fexpr->funcvariadic = agg_variadic;
*invtransfnexpr = (Expr *) fexpr;
}
else
*invtransfnexpr = NULL;
}
/* see if we have a final function */
if (!OidIsValid(finalfn_oid))
{
......
......@@ -11548,20 +11548,32 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
PGresult *res;
int i_aggtransfn;
int i_aggfinalfn;
int i_aggmtransfn;
int i_aggminvtransfn;
int i_aggmfinalfn;
int i_aggsortop;
int i_hypothetical;
int i_aggtranstype;
int i_aggtransspace;
int i_aggmtranstype;
int i_aggmtransspace;
int i_agginitval;
int i_aggminitval;
int i_convertok;
const char *aggtransfn;
const char *aggfinalfn;
const char *aggmtransfn;
const char *aggminvtransfn;
const char *aggmfinalfn;
const char *aggsortop;
char *aggsortconvop;
bool hypothetical;
const char *aggtranstype;
const char *aggtransspace;
const char *aggmtranstype;
const char *aggmtransspace;
const char *agginitval;
const char *aggminitval;
bool convertok;
/* Skip if not to be dumped */
......@@ -11582,9 +11594,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
{
appendPQExpBuffer(query, "SELECT aggtransfn, "
"aggfinalfn, aggtranstype::pg_catalog.regtype, "
"aggmtransfn, aggminvtransfn, aggmfinalfn, "
"aggmtranstype::pg_catalog.regtype, "
"aggsortop::pg_catalog.regoperator, "
"(aggkind = 'h') as hypothetical, "
"aggtransspace, agginitval, "
"aggmtransspace, aggminitval, "
"'t'::boolean AS convertok, "
"pg_catalog.pg_get_function_arguments(p.oid) AS funcargs, "
"pg_catalog.pg_get_function_identity_arguments(p.oid) AS funciargs "
......@@ -11597,9 +11612,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
{
appendPQExpBuffer(query, "SELECT aggtransfn, "
"aggfinalfn, aggtranstype::pg_catalog.regtype, "
"'-' AS aggmtransfn, '-' AS aggminvtransfn, "
"'-' AS aggmfinalfn, 0 AS aggmtranstype, "
"aggsortop::pg_catalog.regoperator, "
"false as hypothetical, "
"0 AS aggtransspace, agginitval, "
"0 AS aggmtransspace, NULL AS aggminitval, "
"'t'::boolean AS convertok, "
"pg_catalog.pg_get_function_arguments(p.oid) AS funcargs, "
"pg_catalog.pg_get_function_identity_arguments(p.oid) AS funciargs "
......@@ -11612,9 +11630,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
{
appendPQExpBuffer(query, "SELECT aggtransfn, "
"aggfinalfn, aggtranstype::pg_catalog.regtype, "
"'-' AS aggmtransfn, '-' AS aggminvtransfn, "
"'-' AS aggmfinalfn, 0 AS aggmtranstype, "
"aggsortop::pg_catalog.regoperator, "
"false as hypothetical, "
"0 AS aggtransspace, agginitval, "
"0 AS aggmtransspace, NULL AS aggminitval, "
"'t'::boolean AS convertok "
"FROM pg_catalog.pg_aggregate a, pg_catalog.pg_proc p "
"WHERE a.aggfnoid = p.oid "
......@@ -11625,9 +11646,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
{
appendPQExpBuffer(query, "SELECT aggtransfn, "
"aggfinalfn, aggtranstype::pg_catalog.regtype, "
"'-' AS aggmtransfn, '-' AS aggminvtransfn, "
"'-' AS aggmfinalfn, 0 AS aggmtranstype, "
"0 AS aggsortop, "
"'f'::boolean as hypothetical, "
"0 AS aggtransspace, agginitval, "
"0 AS aggmtransspace, NULL AS aggminitval, "
"'t'::boolean AS convertok "
"FROM pg_catalog.pg_aggregate a, pg_catalog.pg_proc p "
"WHERE a.aggfnoid = p.oid "
......@@ -11638,9 +11662,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
{
appendPQExpBuffer(query, "SELECT aggtransfn, aggfinalfn, "
"format_type(aggtranstype, NULL) AS aggtranstype, "
"'-' AS aggmtransfn, '-' AS aggminvtransfn, "
"'-' AS aggmfinalfn, 0 AS aggmtranstype, "
"0 AS aggsortop, "
"'f'::boolean as hypothetical, "
"0 AS aggtransspace, agginitval, "
"0 AS aggmtransspace, NULL AS aggminitval, "
"'t'::boolean AS convertok "
"FROM pg_aggregate "
"WHERE oid = '%u'::oid",
......@@ -11651,9 +11678,12 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
appendPQExpBuffer(query, "SELECT aggtransfn1 AS aggtransfn, "
"aggfinalfn, "
"(SELECT typname FROM pg_type WHERE oid = aggtranstype1) AS aggtranstype, "
"'-' AS aggmtransfn, '-' AS aggminvtransfn, "
"'-' AS aggmfinalfn, 0 AS aggmtranstype, "
"0 AS aggsortop, "
"'f'::boolean as hypothetical, "
"0 AS aggtransspace, agginitval1 AS agginitval, "
"0 AS aggmtransspace, NULL AS aggminitval, "
"(aggtransfn2 = 0 and aggtranstype2 = 0 and agginitval2 is null) AS convertok "
"FROM pg_aggregate "
"WHERE oid = '%u'::oid",
......@@ -11664,20 +11694,32 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
i_aggtransfn = PQfnumber(res, "aggtransfn");
i_aggfinalfn = PQfnumber(res, "aggfinalfn");
i_aggmtransfn = PQfnumber(res, "aggmtransfn");
i_aggminvtransfn = PQfnumber(res, "aggminvtransfn");
i_aggmfinalfn = PQfnumber(res, "aggmfinalfn");
i_aggsortop = PQfnumber(res, "aggsortop");
i_hypothetical = PQfnumber(res, "hypothetical");
i_aggtranstype = PQfnumber(res, "aggtranstype");
i_aggtransspace = PQfnumber(res, "aggtransspace");
i_aggmtranstype = PQfnumber(res, "aggmtranstype");
i_aggmtransspace = PQfnumber(res, "aggmtransspace");
i_agginitval = PQfnumber(res, "agginitval");
i_aggminitval = PQfnumber(res, "aggminitval");
i_convertok = PQfnumber(res, "convertok");
aggtransfn = PQgetvalue(res, 0, i_aggtransfn);
aggfinalfn = PQgetvalue(res, 0, i_aggfinalfn);
aggmtransfn = PQgetvalue(res, 0, i_aggmtransfn);
aggminvtransfn = PQgetvalue(res, 0, i_aggminvtransfn);
aggmfinalfn = PQgetvalue(res, 0, i_aggmfinalfn);
aggsortop = PQgetvalue(res, 0, i_aggsortop);
hypothetical = (PQgetvalue(res, 0, i_hypothetical)[0] == 't');
aggtranstype = PQgetvalue(res, 0, i_aggtranstype);
aggtransspace = PQgetvalue(res, 0, i_aggtransspace);
aggmtranstype = PQgetvalue(res, 0, i_aggmtranstype);
aggmtransspace = PQgetvalue(res, 0, i_aggmtransspace);
agginitval = PQgetvalue(res, 0, i_agginitval);
aggminitval = PQgetvalue(res, 0, i_aggminitval);
convertok = (PQgetvalue(res, 0, i_convertok)[0] == 't');
if (fout->remoteVersion >= 80400)
......@@ -11751,6 +11793,32 @@ dumpAgg(Archive *fout, AggInfo *agginfo)
aggfinalfn);
}
if (strcmp(aggmtransfn, "-") != 0)
{
appendPQExpBuffer(details, ",\n MSFUNC = %s,\n MINVFUNC = %s,\n MSTYPE = %s",
aggmtransfn,
aggminvtransfn,
aggmtranstype);
}
if (strcmp(aggmtransspace, "0") != 0)
{
appendPQExpBuffer(details, ",\n MSSPACE = %s",
aggmtransspace);
}
if (!PQgetisnull(res, 0, i_aggminitval))
{
appendPQExpBufferStr(details, ",\n MINITCOND = ");
appendStringLiteralAH(details, aggminitval, fout);
}
if (strcmp(aggmfinalfn, "-") != 0)
{
appendPQExpBuffer(details, ",\n MFINALFUNC = %s",
aggmfinalfn);
}
aggsortconvop = convertOperatorReference(fout, aggsortop);
if (aggsortconvop)
{
......
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201404082
#define CATALOG_VERSION_NO 201404121
#endif
This diff is collapsed.
......@@ -1762,7 +1762,8 @@ typedef struct WindowAggState
Datum endOffsetValue; /* result of endOffset evaluation */
MemoryContext partcontext; /* context for partition-lifespan data */
MemoryContext aggcontext; /* context for each aggregate data */
MemoryContext aggcontext; /* shared context for aggregate working data */
MemoryContext curaggcontext; /* current aggregate's working data */
ExprContext *tmpcontext; /* short-term evaluation context */
bool all_first; /* true if the scan is starting */
......
......@@ -39,8 +39,10 @@ extern void build_aggregate_fnexprs(Oid *agg_input_types,
Oid agg_result_type,
Oid agg_input_collation,
Oid transfn_oid,
Oid invtransfn_oid,
Oid finalfn_oid,
Expr **transfnexpr,
Expr **invtransfnexpr,
Expr **finalfnexpr);
#endif /* PARSE_AGG_H */
......@@ -90,3 +90,38 @@ alter aggregate my_rank(VARIADIC "any" ORDER BY VARIADIC "any")
public | test_rank | bigint | VARIADIC "any" ORDER BY VARIADIC "any" |
(2 rows)
-- moving-aggregate options
CREATE AGGREGATE sumdouble (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi
);
-- invalid: nonstrict inverse with strict forward function
CREATE FUNCTION float8mi_n(float8, float8) RETURNS float8 AS
$$ SELECT $1 - $2; $$
LANGUAGE SQL;
CREATE AGGREGATE invalidsumdouble (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi_n
);
ERROR: strictness of aggregate's forward and inverse transition functions must match
-- invalid: non-matching result types
CREATE FUNCTION float8mi_int(float8, float8) RETURNS int AS
$$ SELECT CAST($1 - $2 AS INT); $$
LANGUAGE SQL;
CREATE AGGREGATE wrongreturntype (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi_int
);
ERROR: return type of inverse transition function float8mi_int is not double precision
......@@ -735,7 +735,7 @@ WHERE aggfnoid = 0 OR aggtransfn = 0 OR
aggkind NOT IN ('n', 'o', 'h') OR
aggnumdirectargs < 0 OR
(aggkind = 'n' AND aggnumdirectargs > 0) OR
aggtranstype = 0 OR aggtransspace < 0;
aggtranstype = 0 OR aggtransspace < 0 OR aggmtransspace < 0;
ctid | aggfnoid
------+----------
(0 rows)
......@@ -827,6 +827,126 @@ WHERE a.aggfnoid = p.oid AND
----------+---------+-----+---------
(0 rows)
-- Check for inconsistent specifications of moving-aggregate columns.
SELECT ctid, aggfnoid::oid
FROM pg_aggregate as p1
WHERE aggmtranstype != 0 AND
(aggmtransfn = 0 OR aggminvtransfn = 0);
ctid | aggfnoid
------+----------
(0 rows)
SELECT ctid, aggfnoid::oid
FROM pg_aggregate as p1
WHERE aggmtranstype = 0 AND
(aggmtransfn != 0 OR aggminvtransfn != 0 OR aggmfinalfn != 0 OR
aggmtransspace != 0 OR aggminitval IS NOT NULL);
ctid | aggfnoid
------+----------
(0 rows)
-- If there is no mfinalfn then the output type must be the mtranstype.
SELECT a.aggfnoid::oid, p.proname
FROM pg_aggregate as a, pg_proc as p
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn != 0 AND
a.aggmfinalfn = 0 AND p.prorettype != a.aggmtranstype;
aggfnoid | proname
----------+---------
(0 rows)
-- Cross-check mtransfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn = ptr.oid AND
(ptr.proretset
OR NOT (ptr.pronargs =
CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
OR NOT physically_coercible(ptr.prorettype, a.aggmtranstype)
OR NOT physically_coercible(a.aggmtranstype, ptr.proargtypes[0])
OR (p.pronargs > 0 AND
NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
);
aggfnoid | proname | oid | proname
----------+---------+-----+---------
(0 rows)
-- Cross-check minvtransfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggminvtransfn = ptr.oid AND
(ptr.proretset
OR NOT (ptr.pronargs =
CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
OR NOT physically_coercible(ptr.prorettype, a.aggmtranstype)
OR NOT physically_coercible(a.aggmtranstype, ptr.proargtypes[0])
OR (p.pronargs > 0 AND
NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
);
aggfnoid | proname | oid | proname
----------+---------+-----+---------
(0 rows)
-- Cross-check mfinalfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
WHERE a.aggfnoid = p.oid AND
a.aggmfinalfn = pfn.oid AND
(pfn.proretset OR
NOT binary_coercible(pfn.prorettype, p.prorettype) OR
NOT binary_coercible(a.aggmtranstype, pfn.proargtypes[0]) OR
CASE WHEN a.aggkind = 'n' THEN pfn.pronargs != 1
ELSE pfn.pronargs != p.pronargs + 1
OR (p.pronargs > 0 AND
NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
END);
aggfnoid | proname | oid | proname
----------+---------+-----+---------
(0 rows)
-- If mtransfn is strict then either minitval should be non-NULL, or
-- input type should match mtranstype so that the first non-null input
-- can be assigned as the state value.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn = ptr.oid AND ptr.proisstrict AND
a.aggminitval IS NULL AND
NOT binary_coercible(p.proargtypes[0], a.aggmtranstype);
aggfnoid | proname | oid | proname
----------+---------+-----+---------
(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
WHERE a.aggfnoid = p.oid AND
a.aggtransfn = ptr.oid AND
a.aggmtransfn = mptr.oid AND
ptr.proisstrict != mptr.proisstrict;
aggfnoid | proname | oid | proname | oid | proname
----------+---------+-----+---------+-----+---------
(0 rows)
-- Cross-check aggsortop (if present) against pg_operator.
-- We expect to find entries for bool_and, bool_or, every, max, and min.
SELECT DISTINCT proname, oprname
......
......@@ -1071,3 +1071,226 @@ SELECT nth_value_def(ten) OVER (PARTITION BY four), ten, four
1 | 3 | 3
(10 rows)
--
-- Test the basic moving-aggregate machinery
--
-- create aggregates that record the series of transform calls (these are
-- intentionally not true inverses)
CREATE FUNCTION logging_sfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT COALESCE($1, '') || '*' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE FUNCTION logging_msfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT COALESCE($1, '') || '+' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE FUNCTION logging_minvfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '-' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE AGGREGATE logging_agg_nonstrict (anyelement)
(
stype = text,
sfunc = logging_sfunc_nonstrict,
mstype = text,
msfunc = logging_msfunc_nonstrict,
minvfunc = logging_minvfunc_nonstrict
);
CREATE AGGREGATE logging_agg_nonstrict_initcond (anyelement)
(
stype = text,
sfunc = logging_sfunc_nonstrict,
mstype = text,
msfunc = logging_msfunc_nonstrict,
minvfunc = logging_minvfunc_nonstrict,
initcond = 'I',
minitcond = 'MI'
);
CREATE FUNCTION logging_sfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '*' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE FUNCTION logging_msfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '+' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE FUNCTION logging_minvfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '-' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE AGGREGATE logging_agg_strict (text)
(
stype = text,
sfunc = logging_sfunc_strict,
mstype = text,
msfunc = logging_msfunc_strict,
minvfunc = logging_minvfunc_strict
);
CREATE AGGREGATE logging_agg_strict_initcond (anyelement)
(
stype = text,
sfunc = logging_sfunc_strict,
mstype = text,
msfunc = logging_msfunc_strict,
minvfunc = logging_minvfunc_strict,
initcond = 'I',
minitcond = 'MI'
);
-- test strict and non-strict cases
SELECT
p::text || ',' || i::text || ':' || COALESCE(v::text, 'NULL') AS row,
logging_agg_nonstrict(v) over wnd as nstrict,
logging_agg_nonstrict_initcond(v) over wnd as nstrict_init,
logging_agg_strict(v::text) over wnd as strict,
logging_agg_strict_initcond(v) over wnd as strict_init
FROM (VALUES
(1, 1, NULL),
(1, 2, 'a'),
(1, 3, 'b'),
(1, 4, NULL),
(1, 5, NULL),
(1, 6, 'c'),
(2, 1, NULL),
(2, 2, 'x'),
(3, 1, 'z')
) AS t(p, i, v)
WINDOW wnd AS (PARTITION BY P ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY p, i;
row | nstrict | nstrict_init | strict | strict_init
----------+-----------------------------------------------+-------------------------------------------------+-----------+----------------
1,1:NULL | +NULL | MI+NULL | | MI
1,2:a | +NULL+'a' | MI+NULL+'a' | a | MI+'a'
1,3:b | +NULL+'a'-NULL+'b' | MI+NULL+'a'-NULL+'b' | a+'b' | MI+'a'+'b'
1,4:NULL | +NULL+'a'-NULL+'b'-'a'+NULL | MI+NULL+'a'-NULL+'b'-'a'+NULL | a+'b'-'a' | MI+'a'+'b'-'a'
1,5:NULL | +NULL+'a'-NULL+'b'-'a'+NULL-'b'+NULL | MI+NULL+'a'-NULL+'b'-'a'+NULL-'b'+NULL | | MI
1,6:c | +NULL+'a'-NULL+'b'-'a'+NULL-'b'+NULL-NULL+'c' | MI+NULL+'a'-NULL+'b'-'a'+NULL-'b'+NULL-NULL+'c' | c | MI+'c'
2,1:NULL | +NULL | MI+NULL | | MI
2,2:x | +NULL+'x' | MI+NULL+'x' | x | MI+'x'
3,1:z | +'z' | MI+'z' | z | MI+'z'
(9 rows)
-- and again, but with filter
SELECT
p::text || ',' || i::text || ':' ||
CASE WHEN f THEN COALESCE(v::text, 'NULL') ELSE '-' END as row,
logging_agg_nonstrict(v) filter(where f) over wnd as nstrict_filt,
logging_agg_nonstrict_initcond(v) filter(where f) over wnd as nstrict_init_filt,
logging_agg_strict(v::text) filter(where f) over wnd as strict_filt,
logging_agg_strict_initcond(v) filter(where f) over wnd as strict_init_filt
FROM (VALUES
(1, 1, true, NULL),
(1, 2, false, 'a'),
(1, 3, true, 'b'),
(1, 4, false, NULL),
(1, 5, false, NULL),
(1, 6, false, 'c'),
(2, 1, false, NULL),
(2, 2, true, 'x'),
(3, 1, true, 'z')
) AS t(p, i, f, v)
WINDOW wnd AS (PARTITION BY p ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY p, i;
row | nstrict_filt | nstrict_init_filt | strict_filt | strict_init_filt
----------+--------------+-------------------+-------------+------------------
1,1:NULL | +NULL | MI+NULL | | MI
1,2:- | +NULL | MI+NULL | | MI
1,3:b | +'b' | MI+'b' | b | MI+'b'
1,4:- | +'b' | MI+'b' | b | MI+'b'
1,5:- | | MI | | MI
1,6:- | | MI | | MI
2,1:- | | MI | | MI
2,2:x | +'x' | MI+'x' | x | MI+'x'
3,1:z | +'z' | MI+'z' | z | MI+'z'
(9 rows)
-- test that volatile arguments disable moving-aggregate mode
SELECT
i::text || ':' || COALESCE(v::text, 'NULL') as row,
logging_agg_strict(v::text)
over wnd as inverse,
logging_agg_strict(v::text || CASE WHEN random() < 0 then '?' ELSE '' END)
over wnd as noinverse
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY i;
row | inverse | noinverse
-----+---------------+-----------
1:a | a | a
2:b | a+'b' | a*'b'
3:c | a+'b'-'a'+'c' | b*'c'
(3 rows)
SELECT
i::text || ':' || COALESCE(v::text, 'NULL') as row,
logging_agg_strict(v::text) filter(where true)
over wnd as inverse,
logging_agg_strict(v::text) filter(where random() >= 0)
over wnd as noinverse
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY i;
row | inverse | noinverse
-----+---------------+-----------
1:a | a | a
2:b | a+'b' | a*'b'
3:c | a+'b'-'a'+'c' | b*'c'
(3 rows)
-- test that non-overlapping windows don't use inverse transitions
SELECT
logging_agg_strict(v::text) OVER wnd
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN CURRENT ROW AND CURRENT ROW)
ORDER BY i;
logging_agg_strict
--------------------
a
b
c
(3 rows)
-- test that returning NULL from the inverse transition functions
-- restarts the aggregation from scratch. The second aggregate is supposed
-- to test cases where only some aggregates restart, the third one checks
-- that one aggregate restarting doesn't cause others to restart.
CREATE FUNCTION sum_int_randrestart_minvfunc(int4, int4) RETURNS int4 AS
$$ SELECT CASE WHEN random() < 0.2 THEN NULL ELSE $1 - $2 END $$
LANGUAGE SQL STRICT;
CREATE AGGREGATE sum_int_randomrestart (int4)
(
stype = int4,
sfunc = int4pl,
mstype = int4,
msfunc = int4pl,
minvfunc = sum_int_randrestart_minvfunc
);
WITH
vs AS (
SELECT i, (random() * 100)::int4 AS v
FROM generate_series(1, 100) AS i
),
sum_following AS (
SELECT i, SUM(v) OVER
(ORDER BY i DESC ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS s
FROM vs
)
SELECT DISTINCT
sum_following.s = sum_int_randomrestart(v) OVER fwd AS eq1,
-sum_following.s = sum_int_randomrestart(-v) OVER fwd AS eq2,
100*3+(vs.i-1)*3 = length(logging_agg_nonstrict(''::text) OVER fwd) AS eq3
FROM vs
JOIN sum_following ON sum_following.i = vs.i
WINDOW fwd AS (
ORDER BY vs.i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
);
eq1 | eq2 | eq3
-----+-----+-----
t | t | t
(1 row)
......@@ -101,3 +101,44 @@ alter aggregate my_rank(VARIADIC "any" ORDER BY VARIADIC "any")
rename to test_rank;
\da test_*
-- moving-aggregate options
CREATE AGGREGATE sumdouble (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi
);
-- invalid: nonstrict inverse with strict forward function
CREATE FUNCTION float8mi_n(float8, float8) RETURNS float8 AS
$$ SELECT $1 - $2; $$
LANGUAGE SQL;
CREATE AGGREGATE invalidsumdouble (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi_n
);
-- invalid: non-matching result types
CREATE FUNCTION float8mi_int(float8, float8) RETURNS int AS
$$ SELECT CAST($1 - $2 AS INT); $$
LANGUAGE SQL;
CREATE AGGREGATE wrongreturntype (float8)
(
stype = float8,
sfunc = float8pl,
mstype = float8,
msfunc = float8pl,
minvfunc = float8mi_int
);
......@@ -592,7 +592,7 @@ WHERE aggfnoid = 0 OR aggtransfn = 0 OR
aggkind NOT IN ('n', 'o', 'h') OR
aggnumdirectargs < 0 OR
(aggkind = 'n' AND aggnumdirectargs > 0) OR
aggtranstype = 0 OR aggtransspace < 0;
aggtranstype = 0 OR aggtransspace < 0 OR aggmtransspace < 0;
-- Make sure the matching pg_proc entry is sensible, too.
......@@ -668,6 +668,107 @@ WHERE a.aggfnoid = p.oid AND
a.agginitval IS NULL AND
NOT binary_coercible(p.proargtypes[0], a.aggtranstype);
-- Check for inconsistent specifications of moving-aggregate columns.
SELECT ctid, aggfnoid::oid
FROM pg_aggregate as p1
WHERE aggmtranstype != 0 AND
(aggmtransfn = 0 OR aggminvtransfn = 0);
SELECT ctid, aggfnoid::oid
FROM pg_aggregate as p1
WHERE aggmtranstype = 0 AND
(aggmtransfn != 0 OR aggminvtransfn != 0 OR aggmfinalfn != 0 OR
aggmtransspace != 0 OR aggminitval IS NOT NULL);
-- If there is no mfinalfn then the output type must be the mtranstype.
SELECT a.aggfnoid::oid, p.proname
FROM pg_aggregate as a, pg_proc as p
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn != 0 AND
a.aggmfinalfn = 0 AND p.prorettype != a.aggmtranstype;
-- Cross-check mtransfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn = ptr.oid AND
(ptr.proretset
OR NOT (ptr.pronargs =
CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
OR NOT physically_coercible(ptr.prorettype, a.aggmtranstype)
OR NOT physically_coercible(a.aggmtranstype, ptr.proargtypes[0])
OR (p.pronargs > 0 AND
NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
);
-- Cross-check minvtransfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggminvtransfn = ptr.oid AND
(ptr.proretset
OR NOT (ptr.pronargs =
CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
OR NOT physically_coercible(ptr.prorettype, a.aggmtranstype)
OR NOT physically_coercible(a.aggmtranstype, ptr.proargtypes[0])
OR (p.pronargs > 0 AND
NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
);
-- Cross-check mfinalfn (if present) against its entry in pg_proc.
SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
WHERE a.aggfnoid = p.oid AND
a.aggmfinalfn = pfn.oid AND
(pfn.proretset OR
NOT binary_coercible(pfn.prorettype, p.prorettype) OR
NOT binary_coercible(a.aggmtranstype, pfn.proargtypes[0]) OR
CASE WHEN a.aggkind = 'n' THEN pfn.pronargs != 1
ELSE pfn.pronargs != p.pronargs + 1
OR (p.pronargs > 0 AND
NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
OR (p.pronargs > 1 AND
NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
OR (p.pronargs > 2 AND
NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
-- we could carry the check further, but 3 args is enough for now
END);
-- If mtransfn is strict then either minitval should be non-NULL, or
-- input type should match mtranstype so that the first non-null input
-- can be assigned as the state value.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
a.aggmtransfn = ptr.oid AND ptr.proisstrict AND
a.aggminitval IS NULL AND
NOT binary_coercible(p.proargtypes[0], a.aggmtranstype);
-- 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
WHERE a.aggfnoid = p.oid AND
a.aggtransfn = ptr.oid AND
a.aggmtransfn = mptr.oid AND
ptr.proisstrict != mptr.proisstrict;
-- Cross-check aggsortop (if present) against pg_operator.
-- We expect to find entries for bool_and, bool_or, every, max, and min.
......
......@@ -284,3 +284,195 @@ SELECT nth_value_def(n := 2, val := ten) OVER (PARTITION BY four), ten, four
SELECT nth_value_def(ten) OVER (PARTITION BY four), ten, four
FROM (SELECT * FROM tenk1 WHERE unique2 < 10 ORDER BY four, ten) s;
--
-- Test the basic moving-aggregate machinery
--
-- create aggregates that record the series of transform calls (these are
-- intentionally not true inverses)
CREATE FUNCTION logging_sfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT COALESCE($1, '') || '*' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE FUNCTION logging_msfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT COALESCE($1, '') || '+' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE FUNCTION logging_minvfunc_nonstrict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '-' || quote_nullable($2) $$
LANGUAGE SQL IMMUTABLE;
CREATE AGGREGATE logging_agg_nonstrict (anyelement)
(
stype = text,
sfunc = logging_sfunc_nonstrict,
mstype = text,
msfunc = logging_msfunc_nonstrict,
minvfunc = logging_minvfunc_nonstrict
);
CREATE AGGREGATE logging_agg_nonstrict_initcond (anyelement)
(
stype = text,
sfunc = logging_sfunc_nonstrict,
mstype = text,
msfunc = logging_msfunc_nonstrict,
minvfunc = logging_minvfunc_nonstrict,
initcond = 'I',
minitcond = 'MI'
);
CREATE FUNCTION logging_sfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '*' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE FUNCTION logging_msfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '+' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE FUNCTION logging_minvfunc_strict(text, anyelement) RETURNS text AS
$$ SELECT $1 || '-' || quote_nullable($2) $$
LANGUAGE SQL STRICT IMMUTABLE;
CREATE AGGREGATE logging_agg_strict (text)
(
stype = text,
sfunc = logging_sfunc_strict,
mstype = text,
msfunc = logging_msfunc_strict,
minvfunc = logging_minvfunc_strict
);
CREATE AGGREGATE logging_agg_strict_initcond (anyelement)
(
stype = text,
sfunc = logging_sfunc_strict,
mstype = text,
msfunc = logging_msfunc_strict,
minvfunc = logging_minvfunc_strict,
initcond = 'I',
minitcond = 'MI'
);
-- test strict and non-strict cases
SELECT
p::text || ',' || i::text || ':' || COALESCE(v::text, 'NULL') AS row,
logging_agg_nonstrict(v) over wnd as nstrict,
logging_agg_nonstrict_initcond(v) over wnd as nstrict_init,
logging_agg_strict(v::text) over wnd as strict,
logging_agg_strict_initcond(v) over wnd as strict_init
FROM (VALUES
(1, 1, NULL),
(1, 2, 'a'),
(1, 3, 'b'),
(1, 4, NULL),
(1, 5, NULL),
(1, 6, 'c'),
(2, 1, NULL),
(2, 2, 'x'),
(3, 1, 'z')
) AS t(p, i, v)
WINDOW wnd AS (PARTITION BY P ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY p, i;
-- and again, but with filter
SELECT
p::text || ',' || i::text || ':' ||
CASE WHEN f THEN COALESCE(v::text, 'NULL') ELSE '-' END as row,
logging_agg_nonstrict(v) filter(where f) over wnd as nstrict_filt,
logging_agg_nonstrict_initcond(v) filter(where f) over wnd as nstrict_init_filt,
logging_agg_strict(v::text) filter(where f) over wnd as strict_filt,
logging_agg_strict_initcond(v) filter(where f) over wnd as strict_init_filt
FROM (VALUES
(1, 1, true, NULL),
(1, 2, false, 'a'),
(1, 3, true, 'b'),
(1, 4, false, NULL),
(1, 5, false, NULL),
(1, 6, false, 'c'),
(2, 1, false, NULL),
(2, 2, true, 'x'),
(3, 1, true, 'z')
) AS t(p, i, f, v)
WINDOW wnd AS (PARTITION BY p ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY p, i;
-- test that volatile arguments disable moving-aggregate mode
SELECT
i::text || ':' || COALESCE(v::text, 'NULL') as row,
logging_agg_strict(v::text)
over wnd as inverse,
logging_agg_strict(v::text || CASE WHEN random() < 0 then '?' ELSE '' END)
over wnd as noinverse
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY i;
SELECT
i::text || ':' || COALESCE(v::text, 'NULL') as row,
logging_agg_strict(v::text) filter(where true)
over wnd as inverse,
logging_agg_strict(v::text) filter(where random() >= 0)
over wnd as noinverse
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN 1 PRECEDING AND CURRENT ROW)
ORDER BY i;
-- test that non-overlapping windows don't use inverse transitions
SELECT
logging_agg_strict(v::text) OVER wnd
FROM (VALUES
(1, 'a'),
(2, 'b'),
(3, 'c')
) AS t(i, v)
WINDOW wnd AS (ORDER BY i ROWS BETWEEN CURRENT ROW AND CURRENT ROW)
ORDER BY i;
-- test that returning NULL from the inverse transition functions
-- restarts the aggregation from scratch. The second aggregate is supposed
-- to test cases where only some aggregates restart, the third one checks
-- that one aggregate restarting doesn't cause others to restart.
CREATE FUNCTION sum_int_randrestart_minvfunc(int4, int4) RETURNS int4 AS
$$ SELECT CASE WHEN random() < 0.2 THEN NULL ELSE $1 - $2 END $$
LANGUAGE SQL STRICT;
CREATE AGGREGATE sum_int_randomrestart (int4)
(
stype = int4,
sfunc = int4pl,
mstype = int4,
msfunc = int4pl,
minvfunc = sum_int_randrestart_minvfunc
);
WITH
vs AS (
SELECT i, (random() * 100)::int4 AS v
FROM generate_series(1, 100) AS i
),
sum_following AS (
SELECT i, SUM(v) OVER
(ORDER BY i DESC ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS s
FROM vs
)
SELECT DISTINCT
sum_following.s = sum_int_randomrestart(v) OVER fwd AS eq1,
-sum_following.s = sum_int_randomrestart(-v) OVER fwd AS eq2,
100*3+(vs.i-1)*3 = length(logging_agg_nonstrict(''::text) OVER fwd) AS eq3
FROM vs
JOIN sum_following ON sum_following.i = vs.i
WINDOW fwd AS (
ORDER BY vs.i ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
);
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