JumbleExpr(jstate, (Node *) expr->args);
JumbleExpr(jstate, (Node *) expr->aggorder);
JumbleExpr(jstate, (Node *) expr->aggdistinct);
+ JumbleExpr(jstate, (Node *) expr->aggfilter);
}
break;
case T_WindowFunc:
APP_JUMB(expr->winfnoid);
APP_JUMB(expr->winref);
JumbleExpr(jstate, (Node *) expr->args);
+ JumbleExpr(jstate, (Node *) expr->aggfilter);
}
break;
case T_ArrayRef:
</row>
<row>
<entry><token>FILTER</token></entry>
- <entry></entry>
+ <entry>non-reserved</entry>
<entry>reserved</entry>
<entry>reserved</entry>
<entry></entry>
making up each group, producing a separate value for each group
(whereas without <literal>GROUP BY</literal>, an aggregate
produces a single value computed across all the selected rows).
+ The set of rows fed to the aggregate function can be further filtered by
+ attaching a <literal>FILTER</literal> clause to the aggregate function
+ call; see <xref linkend="syntax-aggregates"> for more information. When
+ a <literal>FILTER</literal> clause is present, only those rows matching it
+ are included.
When <literal>GROUP BY</literal> is present, it is not valid for
the <command>SELECT</command> list expressions to refer to
ungrouped columns except within aggregate functions or if the
<secondary>invocation</secondary>
</indexterm>
+ <indexterm zone="syntax-aggregates">
+ <primary>filter</primary>
+ </indexterm>
+
<para>
An <firstterm>aggregate expression</firstterm> represents the
application of an aggregate function across the rows selected by a
syntax of an aggregate expression is one of the following:
<synopsis>
-<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
-<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
-<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] )
-<replaceable>aggregate_name</replaceable> ( * )
+<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
+<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
+<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] [ <replaceable>order_by_clause</replaceable> ] ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
+<replaceable>aggregate_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ]
</synopsis>
where <replaceable>aggregate_name</replaceable> is a previously
- defined aggregate (possibly qualified with a schema name),
+ defined aggregate (possibly qualified with a schema name) and
<replaceable>expression</replaceable> is
any value expression that does not itself contain an aggregate
- expression or a window function call, and
- <replaceable>order_by_clause</replaceable> is a optional
- <literal>ORDER BY</> clause as described below.
+ expression or a window function call. The optional
+ <replaceable>order_by_clause</replaceable> and
+ <replaceable>filter_clause</replaceable> are described below.
</para>
<para>
distinct non-null values of <literal>f1</literal>.
</para>
+ <para>
+ If <literal>FILTER</literal> is specified, then only the input
+ rows for which the <replaceable>filter_clause</replaceable>
+ evaluates to true are fed to the aggregate function; other rows
+ are discarded. For example:
+<programlisting>
+SELECT
+ count(*) AS unfiltered,
+ count(*) FILTER (WHERE i < 5) AS filtered
+FROM generate_series(1,10) AS s(i);
+ unfiltered | filtered
+------------+----------
+ 10 | 4
+(1 row)
+</programlisting>
+ </para>
+
<para>
Ordinarily, the input rows are fed to the aggregate function in an
unspecified order. In many cases this does not matter; for example,
The syntax of a window function call is one of the following:
<synopsis>
-<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) OVER ( <replaceable class="parameter">window_definition</replaceable> )
-<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) OVER <replaceable>window_name</replaceable>
-<replaceable>function_name</replaceable> ( * ) OVER ( <replaceable class="parameter">window_definition</replaceable> )
-<replaceable>function_name</replaceable> ( * ) OVER <replaceable>window_name</replaceable>
+<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
+<replaceable>function_name</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional>) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
+<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER ( <replaceable class="parameter">window_definition</replaceable> )
+<replaceable>function_name</replaceable> ( * ) [ FILTER ( WHERE <replaceable>filter_clause</replaceable> ) ] OVER <replaceable>window_name</replaceable>
</synopsis>
where <replaceable class="parameter">window_definition</replaceable>
has the syntax
The built-in window functions are described in <xref
linkend="functions-window-table">. Other window functions can be added by
the user. Also, any built-in or user-defined aggregate function can be
- used as a window function.
+ used as a window function. Only aggregate window functions accept
+ a <literal>FILTER</literal> clause.
</para>
<para>
astate->args = (List *) ExecInitExpr((Expr *) aggref->args,
parent);
+ astate->aggfilter = ExecInitExpr(aggref->aggfilter,
+ parent);
/*
* Complain if the aggregate's arguments contain any
wfstate->args = (List *) ExecInitExpr((Expr *) wfunc->args,
parent);
+ wfstate->aggfilter = ExecInitExpr(wfunc->aggfilter,
+ parent);
/*
* Complain if the windowfunc's arguments contain any
}
/*
- * Don't examine the arguments of Aggrefs or WindowFuncs, because those do
- * not represent expressions to be evaluated within the overall
- * targetlist's econtext.
+ * Don't examine the arguments or filters of Aggrefs or WindowFuncs,
+ * because those do not represent expressions to be evaluated within the
+ * overall targetlist's econtext.
*/
if (IsA(node, Aggref))
return false;
param = ParseFuncOrColumn(pstate,
list_make1(subfield),
list_make1(param),
- NIL, false, false, false,
+ NIL, NULL, false, false, false,
NULL, true, cref->location);
}
{
AggStatePerAgg peraggstate = &aggstate->peragg[aggno];
AggStatePerGroup pergroupstate = &pergroup[aggno];
+ ExprState *filter = peraggstate->aggrefstate->aggfilter;
int nargs = peraggstate->numArguments;
int i;
TupleTableSlot *slot;
+ /* Skip anything FILTERed out */
+ if (filter)
+ {
+ bool isnull;
+ Datum res;
+
+ res = ExecEvalExprSwitchContext(filter, aggstate->tmpcontext,
+ &isnull, NULL);
+ if (isnull || !DatumGetBool(res))
+ continue;
+ }
+
/* Evaluate the current input expressions for this aggregate */
slot = ExecProject(peraggstate->evalproj, NULL);
int i;
MemoryContext oldContext;
ExprContext *econtext = winstate->tmpcontext;
+ ExprState *filter = wfuncstate->aggfilter;
oldContext = MemoryContextSwitchTo(econtext->ecxt_per_tuple_memory);
+ /* Skip anything FILTERed out */
+ if (filter)
+ {
+ bool isnull;
+ Datum res = ExecEvalExpr(filter, econtext, &isnull, NULL);
+
+ if (isnull || !DatumGetBool(res))
+ {
+ MemoryContextSwitchTo(oldContext);
+ return;
+ }
+ }
+
/* We start from 1, since the 0th arg will be the transition value */
i = 1;
foreach(arg, wfuncstate->args)
COPY_NODE_FIELD(args);
COPY_NODE_FIELD(aggorder);
COPY_NODE_FIELD(aggdistinct);
+ COPY_NODE_FIELD(aggfilter);
COPY_SCALAR_FIELD(aggstar);
COPY_SCALAR_FIELD(agglevelsup);
COPY_LOCATION_FIELD(location);
COPY_SCALAR_FIELD(wincollid);
COPY_SCALAR_FIELD(inputcollid);
COPY_NODE_FIELD(args);
+ COPY_NODE_FIELD(aggfilter);
COPY_SCALAR_FIELD(winref);
COPY_SCALAR_FIELD(winstar);
COPY_SCALAR_FIELD(winagg);
COPY_NODE_FIELD(funcname);
COPY_NODE_FIELD(args);
COPY_NODE_FIELD(agg_order);
+ COPY_NODE_FIELD(agg_filter);
COPY_SCALAR_FIELD(agg_star);
COPY_SCALAR_FIELD(agg_distinct);
COPY_SCALAR_FIELD(func_variadic);
COMPARE_NODE_FIELD(args);
COMPARE_NODE_FIELD(aggorder);
COMPARE_NODE_FIELD(aggdistinct);
+ COMPARE_NODE_FIELD(aggfilter);
COMPARE_SCALAR_FIELD(aggstar);
COMPARE_SCALAR_FIELD(agglevelsup);
COMPARE_LOCATION_FIELD(location);
COMPARE_SCALAR_FIELD(wincollid);
COMPARE_SCALAR_FIELD(inputcollid);
COMPARE_NODE_FIELD(args);
+ COMPARE_NODE_FIELD(aggfilter);
COMPARE_SCALAR_FIELD(winref);
COMPARE_SCALAR_FIELD(winstar);
COMPARE_SCALAR_FIELD(winagg);
COMPARE_NODE_FIELD(funcname);
COMPARE_NODE_FIELD(args);
COMPARE_NODE_FIELD(agg_order);
+ COMPARE_NODE_FIELD(agg_filter);
COMPARE_SCALAR_FIELD(agg_star);
COMPARE_SCALAR_FIELD(agg_distinct);
COMPARE_SCALAR_FIELD(func_variadic);
n->args = args;
n->location = location;
n->agg_order = NIL;
+ n->agg_filter = NULL;
n->agg_star = FALSE;
n->agg_distinct = FALSE;
n->func_variadic = FALSE;
if (expression_tree_walker((Node *) expr->aggdistinct,
walker, context))
return true;
+ if (walker((Node *) expr->aggfilter, context))
+ return true;
}
break;
case T_WindowFunc:
if (expression_tree_walker((Node *) expr->args,
walker, context))
return true;
+ if (walker((Node *) expr->aggfilter, context))
+ return true;
}
break;
case T_ArrayRef:
MUTATE(newnode->args, aggref->args, List *);
MUTATE(newnode->aggorder, aggref->aggorder, List *);
MUTATE(newnode->aggdistinct, aggref->aggdistinct, List *);
+ MUTATE(newnode->aggfilter, aggref->aggfilter, Expr *);
return (Node *) newnode;
}
break;
FLATCOPY(newnode, wfunc, WindowFunc);
MUTATE(newnode->args, wfunc->args, List *);
+ MUTATE(newnode->aggfilter, wfunc->aggfilter, Expr *);
return (Node *) newnode;
}
break;
return true;
if (walker(fcall->agg_order, context))
return true;
+ if (walker(fcall->agg_filter, context))
+ return true;
if (walker(fcall->over, context))
return true;
/* function name is deemed uninteresting */
WRITE_NODE_FIELD(args);
WRITE_NODE_FIELD(aggorder);
WRITE_NODE_FIELD(aggdistinct);
+ WRITE_NODE_FIELD(aggfilter);
WRITE_BOOL_FIELD(aggstar);
WRITE_UINT_FIELD(agglevelsup);
WRITE_LOCATION_FIELD(location);
WRITE_OID_FIELD(wincollid);
WRITE_OID_FIELD(inputcollid);
WRITE_NODE_FIELD(args);
+ WRITE_NODE_FIELD(aggfilter);
WRITE_UINT_FIELD(winref);
WRITE_BOOL_FIELD(winstar);
WRITE_BOOL_FIELD(winagg);
WRITE_NODE_FIELD(funcname);
WRITE_NODE_FIELD(args);
WRITE_NODE_FIELD(agg_order);
+ WRITE_NODE_FIELD(agg_filter);
WRITE_BOOL_FIELD(agg_star);
WRITE_BOOL_FIELD(agg_distinct);
WRITE_BOOL_FIELD(func_variadic);
READ_NODE_FIELD(args);
READ_NODE_FIELD(aggorder);
READ_NODE_FIELD(aggdistinct);
+ READ_NODE_FIELD(aggfilter);
READ_BOOL_FIELD(aggstar);
READ_UINT_FIELD(agglevelsup);
READ_LOCATION_FIELD(location);
READ_OID_FIELD(wincollid);
READ_OID_FIELD(inputcollid);
READ_NODE_FIELD(args);
+ READ_NODE_FIELD(aggfilter);
READ_UINT_FIELD(winref);
READ_BOOL_FIELD(winstar);
READ_BOOL_FIELD(winagg);
startup_cost += argcosts.startup;
wfunccost += argcosts.per_tuple;
+ /*
+ * Add the filter's cost to per-input-row costs. XXX We should reduce
+ * input expression costs according to filter selectivity.
+ */
+ cost_qual_eval_node(&argcosts, (Node *) wfunc->aggfilter, root);
+ startup_cost += argcosts.startup;
+ wfunccost += argcosts.per_tuple;
+
total_cost += wfunccost * input_tuples;
}
*/
if (aggref->aggorder != NIL)
return true;
+ /*
+ * We might implement the optimization when a FILTER clause is present
+ * by adding the filter to the quals of the generated subquery.
+ */
+ if (aggref->aggfilter != NULL)
+ return true;
/* note: we do not care if DISTINCT is mentioned ... */
aggsortop = fetch_agg_sort_op(aggref->aggfnoid);
costs->transCost.startup += argcosts.startup;
costs->transCost.per_tuple += argcosts.per_tuple;
+ /*
+ * Add the filter's cost to per-input-row costs. XXX We should reduce
+ * input expression costs according to filter selectivity.
+ */
+ cost_qual_eval_node(&argcosts, (Node *) aggref->aggfilter,
+ context->root);
+ costs->transCost.startup += argcosts.startup;
+ costs->transCost.per_tuple += argcosts.per_tuple;
+
/* extract argument types (ignoring any ORDER BY expressions) */
inputTypes = (Oid *) palloc(sizeof(Oid) * list_length(aggref->args));
numArguments = 0;
/*
* Complain if the aggregate's arguments contain any aggregates;
- * nested agg functions are semantically nonsensical.
+ * nested agg functions are semantically nonsensical. Aggregates in
+ * the FILTER clause are detected in transformAggregateCall().
*/
if (contain_agg_clause((Node *) aggref->args))
ereport(ERROR,
/*
* Complain if the window function's arguments contain window
- * functions
+ * functions. Window functions in the FILTER clause are detected in
+ * transformAggregateCall().
*/
if (contain_window_function((Node *) wfunc->args))
ereport(ERROR,
opt_frame_clause frame_extent frame_bound
%type <str> opt_existing_window_name
%type <boolean> opt_if_not_exists
+%type <node> filter_clause
/*
* Non-keyword token types. These are hard-wired into the "flex" lexer.
EXCLUDE EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN
EXTENSION EXTERNAL EXTRACT
- FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD
- FREEZE FROM FULL FUNCTION FUNCTIONS
+ FALSE_P FAMILY FETCH FILTER FIRST_P FLOAT_P FOLLOWING FOR
+ FORCE FOREIGN FORWARD FREEZE FROM FULL FUNCTION FUNCTIONS
GLOBAL GRANT GRANTED GREATEST GROUP_P
* (Note that many of the special SQL functions wouldn't actually make any
* sense as functional index entries, but we ignore that consideration here.)
*/
-func_expr: func_application over_clause
+func_expr: func_application filter_clause over_clause
{
FuncCall *n = (FuncCall*)$1;
- n->over = $2;
+ n->agg_filter = $2;
+ n->over = $3;
$$ = (Node*)n;
}
| func_expr_common_subexpr
}
;
+filter_clause:
+ FILTER '(' WHERE a_expr ')' { $$ = $4; }
+ | /*EMPTY*/ { $$ = NULL; }
+ ;
+
over_clause: OVER window_specification
{ $$ = $2; }
| OVER ColId
| EXTENSION
| EXTERNAL
| FAMILY
+ | FILTER
| FIRST_P
| FOLLOWING
| FORCE
int sublevels_up;
} check_ungrouped_columns_context;
-static int check_agg_arguments(ParseState *pstate, List *args);
+static int check_agg_arguments(ParseState *pstate, List *args, Expr *filter);
static bool check_agg_arguments_walker(Node *node,
check_agg_arguments_context *context);
static void check_ungrouped_columns(Node *node, ParseState *pstate, Query *qry,
* Check the arguments to compute the aggregate's level and detect
* improper nesting.
*/
- min_varlevel = check_agg_arguments(pstate, agg->args);
+ min_varlevel = check_agg_arguments(pstate, agg->args, agg->aggfilter);
agg->agglevelsup = min_varlevel;
/* Mark the correct pstate level as having aggregates */
case EXPR_KIND_HAVING:
/* okay */
break;
+ case EXPR_KIND_FILTER:
+ errkind = true;
+ break;
case EXPR_KIND_WINDOW_PARTITION:
/* okay */
break;
* one is its parent, etc).
*
* The aggregate's level is the same as the level of the lowest-level variable
- * or aggregate in its arguments; or if it contains no variables at all, we
- * presume it to be local.
+ * or aggregate in its arguments or filter expression; or if it contains no
+ * variables at all, we presume it to be local.
*
* We also take this opportunity to detect any aggregates or window functions
* nested within the arguments. We can throw error immediately if we find
* which we can't know until we finish scanning the arguments.
*/
static int
-check_agg_arguments(ParseState *pstate, List *args)
+check_agg_arguments(ParseState *pstate, List *args, Expr *filter)
{
int agglevel;
check_agg_arguments_context context;
check_agg_arguments_walker,
(void *) &context);
+ (void) expression_tree_walker((Node *) filter,
+ check_agg_arguments_walker,
+ (void *) &context);
+
/*
* If we found no vars nor aggs at all, it's a level-zero aggregate;
* otherwise, its level is the minimum of vars or aggs.
case EXPR_KIND_HAVING:
errkind = true;
break;
+ case EXPR_KIND_FILTER:
+ errkind = true;
+ break;
case EXPR_KIND_WINDOW_PARTITION:
case EXPR_KIND_WINDOW_ORDER:
case EXPR_KIND_WINDOW_FRAME_RANGE:
/*
* If we find an aggregate call of the original level, do not recurse into
- * its arguments; ungrouped vars in the arguments are not an error. We can
- * also skip looking at the arguments of aggregates of higher levels,
- * since they could not possibly contain Vars that are of concern to us
- * (see transformAggregateCall). We do need to look into the arguments of
- * aggregates of lower levels, however.
+ * its arguments or filter; ungrouped vars there are not an error. We can
+ * also skip looking at aggregates of higher levels, since they could not
+ * possibly contain Vars of concern to us (see transformAggregateCall).
+ * We do need to look at aggregates of lower levels, however.
*/
if (IsA(node, Aggref) &&
(int) ((Aggref *) node)->agglevelsup >= context->sublevels_up)
* the case above for T_TargetEntry will apply
* appropriate checks to agg ORDER BY items.
*
+ * Likewise, we assign collations for the (bool)
+ * expression in aggfilter, independently of any
+ * other args.
+ *
* We need not recurse into the aggorder or
* aggdistinct lists, because those contain only
* SortGroupClause nodes which we need not
(void) assign_collations_walker((Node *) tle,
&loccontext);
}
+
+ assign_expr_collations(context->pstate,
+ (Node *) aggref->aggfilter);
+ }
+ break;
+ case T_WindowFunc:
+ {
+ /*
+ * WindowFunc requires special processing only for
+ * its aggfilter clause, as for aggregates.
+ */
+ WindowFunc *wfunc = (WindowFunc *) node;
+
+ (void) assign_collations_walker((Node *) wfunc->args,
+ &loccontext);
+
+ assign_expr_collations(context->pstate,
+ (Node *) wfunc->aggfilter);
}
break;
case T_CaseExpr:
#include "nodes/nodeFuncs.h"
#include "optimizer/var.h"
#include "parser/analyze.h"
+#include "parser/parse_clause.h"
#include "parser/parse_coerce.h"
#include "parser/parse_collate.h"
#include "parser/parse_expr.h"
newresult = ParseFuncOrColumn(pstate,
list_make1(n),
list_make1(result),
- NIL, false, false, false,
+ NIL, NULL, false, false, false,
NULL, true, location);
if (newresult == NULL)
unknown_attribute(pstate, result, strVal(n), location);
node = ParseFuncOrColumn(pstate,
list_make1(makeString(colname)),
list_make1(node),
- NIL, false, false, false,
+ NIL, NULL, false, false, false,
NULL, true, cref->location);
}
break;
node = ParseFuncOrColumn(pstate,
list_make1(makeString(colname)),
list_make1(node),
- NIL, false, false, false,
+ NIL, NULL, false, false, false,
NULL, true, cref->location);
}
break;
node = ParseFuncOrColumn(pstate,
list_make1(makeString(colname)),
list_make1(node),
- NIL, false, false, false,
+ NIL, NULL, false, false, false,
NULL, true, cref->location);
}
break;
{
List *targs;
ListCell *args;
+ Expr *tagg_filter;
/* Transform the list of arguments ... */
targs = NIL;
(Node *) lfirst(args)));
}
+ /*
+ * Transform the aggregate filter using transformWhereClause(), to which
+ * FILTER is virtually identical...
+ */
+ tagg_filter = NULL;
+ if (fn->agg_filter != NULL)
+ tagg_filter = (Expr *)
+ transformWhereClause(pstate, (Node *) fn->agg_filter,
+ EXPR_KIND_FILTER, "FILTER");
+
/* ... and hand off to ParseFuncOrColumn */
return ParseFuncOrColumn(pstate,
fn->funcname,
targs,
fn->agg_order,
+ tagg_filter,
fn->agg_star,
fn->agg_distinct,
fn->func_variadic,
case EXPR_KIND_FROM_FUNCTION:
case EXPR_KIND_WHERE:
case EXPR_KIND_HAVING:
+ case EXPR_KIND_FILTER:
case EXPR_KIND_WINDOW_PARTITION:
case EXPR_KIND_WINDOW_ORDER:
case EXPR_KIND_WINDOW_FRAME_RANGE:
return "WHERE";
case EXPR_KIND_HAVING:
return "HAVING";
+ case EXPR_KIND_FILTER:
+ return "FILTER";
case EXPR_KIND_WINDOW_PARTITION:
return "window PARTITION BY";
case EXPR_KIND_WINDOW_ORDER:
* Also, when is_column is true, we return NULL on failure rather than
* reporting a no-such-function error.
*
- * The argument expressions (in fargs) must have been transformed already.
- * But the agg_order expressions, if any, have not been.
+ * The argument expressions (in fargs) and filter must have been transformed
+ * already. But the agg_order expressions, if any, have not been.
*/
Node *
ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
- List *agg_order, bool agg_star, bool agg_distinct,
- bool func_variadic,
+ List *agg_order, Expr *agg_filter,
+ bool agg_star, bool agg_distinct, bool func_variadic,
WindowDef *over, bool is_column, int location)
{
Oid rettype;
* the "function call" could be a projection. We also check that there
* wasn't any aggregate or variadic decoration, nor an argument name.
*/
- if (nargs == 1 && agg_order == NIL && !agg_star && !agg_distinct &&
- over == NULL && !func_variadic && argnames == NIL &&
+ if (nargs == 1 && agg_order == NIL && agg_filter == NULL && !agg_star &&
+ !agg_distinct && over == NULL && !func_variadic && argnames == NIL &&
list_length(funcname) == 1)
{
Oid argtype = actual_arg_types[0];
errmsg("ORDER BY specified, but %s is not an aggregate function",
NameListToString(funcname)),
parser_errposition(pstate, location)));
+ if (agg_filter)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("FILTER specified, but %s is not an aggregate function",
+ NameListToString(funcname)),
+ parser_errposition(pstate, location)));
if (over)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
/* aggcollid and inputcollid will be set by parse_collate.c */
/* args, aggorder, aggdistinct will be set by transformAggregateCall */
aggref->aggstar = agg_star;
+ aggref->aggfilter = agg_filter;
/* agglevelsup will be set by transformAggregateCall */
aggref->location = location;
/* winref will be set by transformWindowFuncCall */
wfunc->winstar = agg_star;
wfunc->winagg = (fdresult == FUNCDETAIL_AGGREGATE);
+ wfunc->aggfilter = agg_filter;
wfunc->location = location;
/*
NameListToString(funcname)),
parser_errposition(pstate, location)));
+ /*
+ * Reject window functions which are not aggregates in the case of
+ * FILTER.
+ */
+ if (!wfunc->winagg && agg_filter)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("FILTER is not implemented in non-aggregate window functions"),
+ parser_errposition(pstate, location)));
+
/*
* ordered aggs not allowed in windows yet
*/
appendStringInfoString(buf, " ORDER BY ");
get_rule_orderby(aggref->aggorder, aggref->args, false, context);
}
+
+ if (aggref->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ get_rule_expr((Node *) aggref->aggfilter, context, false);
+ }
+
appendStringInfoChar(buf, ')');
}
appendStringInfoChar(buf, '*');
else
get_rule_expr((Node *) wfunc->args, context, true);
+
+ if (wfunc->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ get_rule_expr((Node *) wfunc->aggfilter, context, false);
+ }
+
appendStringInfoString(buf, ") OVER ");
foreach(l, context->windowClause)
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201307051
+#define CATALOG_VERSION_NO 201307161
#endif
{
ExprState xprstate;
List *args; /* states of argument expressions */
+ ExprState *aggfilter; /* FILTER expression */
int aggno; /* ID number for agg within its plan node */
} AggrefExprState;
{
ExprState xprstate;
List *args; /* states of argument expressions */
+ ExprState *aggfilter; /* FILTER expression */
int wfuncno; /* ID number for wfunc within its plan node */
} WindowFuncExprState;
* agg_star indicates we saw a 'foo(*)' construct, while agg_distinct
* indicates we saw 'foo(DISTINCT ...)'. In any of these cases, the
* construct *must* be an aggregate call. Otherwise, it might be either an
- * aggregate or some other kind of function. However, if OVER is present
- * it had better be an aggregate or window function.
+ * aggregate or some other kind of function. However, if FILTER or OVER is
+ * present it had better be an aggregate or window function.
*
* Normally, you'd initialize this via makeFuncCall() and then only
* change the parts of the struct its defaults don't match afterwards
List *funcname; /* qualified name of function */
List *args; /* the arguments (list of exprs) */
List *agg_order; /* ORDER BY (list of SortBy) */
+ Node *agg_filter; /* FILTER clause, if any */
bool agg_star; /* argument was really '*' */
bool agg_distinct; /* arguments were labeled DISTINCT */
bool func_variadic; /* last argument was labeled VARIADIC */
List *args; /* arguments and sort expressions */
List *aggorder; /* ORDER BY (list of SortGroupClause) */
List *aggdistinct; /* DISTINCT (list of SortGroupClause) */
+ Expr *aggfilter; /* FILTER expression */
bool aggstar; /* TRUE if argument list was really '*' */
Index agglevelsup; /* > 0 if agg belongs to outer query */
int location; /* token location, or -1 if unknown */
Oid wincollid; /* OID of collation of result */
Oid inputcollid; /* OID of collation that function should use */
List *args; /* arguments to the window function */
+ Expr *aggfilter; /* FILTER expression */
Index winref; /* index of associated WindowClause */
bool winstar; /* TRUE if argument list was really '*' */
bool winagg; /* is function a simple aggregate? */
PG_KEYWORD("false", FALSE_P, RESERVED_KEYWORD)
PG_KEYWORD("family", FAMILY, UNRESERVED_KEYWORD)
PG_KEYWORD("fetch", FETCH, RESERVED_KEYWORD)
+PG_KEYWORD("filter", FILTER, UNRESERVED_KEYWORD)
PG_KEYWORD("first", FIRST_P, UNRESERVED_KEYWORD)
PG_KEYWORD("float", FLOAT_P, COL_NAME_KEYWORD)
PG_KEYWORD("following", FOLLOWING, UNRESERVED_KEYWORD)
} FuncDetailCode;
-extern Node *ParseFuncOrColumn(ParseState *pstate,
- List *funcname, List *fargs,
- List *agg_order, bool agg_star, bool agg_distinct,
- bool func_variadic,
+extern Node *ParseFuncOrColumn(ParseState *pstate, List *funcname, List *fargs,
+ List *agg_order, Expr *agg_filter,
+ bool agg_star, bool agg_distinct, bool func_variadic,
WindowDef *over, bool is_column, int location);
extern FuncDetailCode func_get_detail(List *funcname,
EXPR_KIND_FROM_FUNCTION, /* function in FROM clause */
EXPR_KIND_WHERE, /* WHERE */
EXPR_KIND_HAVING, /* HAVING */
+ EXPR_KIND_FILTER, /* FILTER */
EXPR_KIND_WINDOW_PARTITION, /* window definition PARTITION BY */
EXPR_KIND_WINDOW_ORDER, /* window definition ORDER BY */
EXPR_KIND_WINDOW_FRAME_RANGE, /* window frame clause with RANGE */
(1 row)
drop table bytea_test_table;
+-- FILTER tests
+select min(unique1) filter (where unique1 > 100) from tenk1;
+ min
+-----
+ 101
+(1 row)
+
+select ten, sum(distinct four) filter (where four::text ~ '123') from onek a
+group by ten;
+ ten | sum
+-----+-----
+ 0 |
+ 1 |
+ 2 |
+ 3 |
+ 4 |
+ 5 |
+ 6 |
+ 7 |
+ 8 |
+ 9 |
+(10 rows)
+
+select ten, sum(distinct four) filter (where four > 10) from onek a
+group by ten
+having exists (select 1 from onek b where sum(distinct a.four) = b.four);
+ ten | sum
+-----+-----
+ 0 |
+ 2 |
+ 4 |
+ 6 |
+ 8 |
+(5 rows)
+
+select max(foo COLLATE "C") filter (where (bar collate "POSIX") > '0')
+from (values ('a', 'b')) AS v(foo,bar);
+ max
+-----
+ a
+(1 row)
+
+-- outer reference in FILTER (PostgreSQL extension)
+select (select count(*)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- inner query is aggregation query
+ count
+-------
+ 1
+ 1
+(2 rows)
+
+select (select count(*) filter (where outer_c <> 0)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- outer query is aggregation query
+ count
+-------
+ 2
+(1 row)
+
+select (select count(inner_c) filter (where outer_c <> 0)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- inner query is aggregation query
+ count
+-------
+ 1
+ 1
+(2 rows)
+
+select
+ (select max((select i.unique2 from tenk1 i where i.unique1 = o.unique1))
+ filter (where o.unique1 < 10))
+from tenk1 o; -- outer query is aggregation query
+ max
+------
+ 9998
+(1 row)
+
+-- subquery in FILTER clause (PostgreSQL extension)
+select sum(unique1) FILTER (WHERE
+ unique1 IN (SELECT unique1 FROM onek where unique1 < 100)) FROM tenk1;
+ sum
+------
+ 4950
+(1 row)
+
+-- exercise lots of aggregate parts with FILTER
+select aggfns(distinct a,b,c order by a,c using ~<~,b) filter (where a > 1)
+ from (values (1,3,'foo'),(0,null,null),(2,2,'bar'),(3,1,'baz')) v(a,b,c),
+ generate_series(1,2) i;
+ aggfns
+---------------------------
+ {"(2,2,bar)","(3,1,baz)"}
+(1 row)
+
ERROR: argument of ntile must be greater than zero
SELECT nth_value(four, 0) OVER (ORDER BY ten), ten, four FROM tenk1;
ERROR: argument of nth_value must be greater than zero
+-- filter
+SELECT sum(salary), row_number() OVER (ORDER BY depname), sum(
+ sum(salary) FILTER (WHERE enroll_date > '2007-01-01')
+) FILTER (WHERE depname <> 'sales') OVER (ORDER BY depname DESC) AS "filtered_sum",
+ depname
+FROM empsalary GROUP BY depname;
+ sum | row_number | filtered_sum | depname
+-------+------------+--------------+-----------
+ 14600 | 3 | | sales
+ 7400 | 2 | 3500 | personnel
+ 25100 | 1 | 22600 | develop
+(3 rows)
+
-- cleanup
DROP TABLE empsalary;
select string_agg(v, decode('ee', 'hex')) from bytea_test_table;
drop table bytea_test_table;
+
+-- FILTER tests
+
+select min(unique1) filter (where unique1 > 100) from tenk1;
+
+select ten, sum(distinct four) filter (where four::text ~ '123') from onek a
+group by ten;
+
+select ten, sum(distinct four) filter (where four > 10) from onek a
+group by ten
+having exists (select 1 from onek b where sum(distinct a.four) = b.four);
+
+select max(foo COLLATE "C") filter (where (bar collate "POSIX") > '0')
+from (values ('a', 'b')) AS v(foo,bar);
+
+-- outer reference in FILTER (PostgreSQL extension)
+select (select count(*)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- inner query is aggregation query
+select (select count(*) filter (where outer_c <> 0)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- outer query is aggregation query
+select (select count(inner_c) filter (where outer_c <> 0)
+ from (values (1)) t0(inner_c))
+from (values (2),(3)) t1(outer_c); -- inner query is aggregation query
+select
+ (select max((select i.unique2 from tenk1 i where i.unique1 = o.unique1))
+ filter (where o.unique1 < 10))
+from tenk1 o; -- outer query is aggregation query
+
+-- subquery in FILTER clause (PostgreSQL extension)
+select sum(unique1) FILTER (WHERE
+ unique1 IN (SELECT unique1 FROM onek where unique1 < 100)) FROM tenk1;
+
+-- exercise lots of aggregate parts with FILTER
+select aggfns(distinct a,b,c order by a,c using ~<~,b) filter (where a > 1)
+ from (values (1,3,'foo'),(0,null,null),(2,2,'bar'),(3,1,'baz')) v(a,b,c),
+ generate_series(1,2) i;
SELECT nth_value(four, 0) OVER (ORDER BY ten), ten, four FROM tenk1;
+-- filter
+
+SELECT sum(salary), row_number() OVER (ORDER BY depname), sum(
+ sum(salary) FILTER (WHERE enroll_date > '2007-01-01')
+) FILTER (WHERE depname <> 'sales') OVER (ORDER BY depname DESC) AS "filtered_sum",
+ depname
+FROM empsalary GROUP BY depname;
+
-- cleanup
DROP TABLE empsalary;