Aggregate Push Down - Performing aggregation on foreign server
Hi all,
Attached is the patch which adds support to push down aggregation and
grouping
to the foreign server for postgres_fdw. Performing aggregation on foreign
server results into fetching fewer rows from foreign side as compared to
fetching all the rows and aggregating/grouping locally. Performing grouping
on
foreign server may use indexes if available. So pushing down aggregates/
grouping on foreign server performs better than doing that locally.
(Attached
EXPLAIN output for few simple grouping queries, with and without push down).
Here are the few details of the implementation
Creating Paths:
Implements the FDW hook GetForeignUpperPaths, which adds foreign scan path
to
the output relation when upper relation kind is UPPERREL_GROUP_AGG. This
path
represents the aggregation/grouping operations to be performed on the
foreign
server. We are able to push down aggregation/grouping if (implemented in
foreign_grouping_ok()),
a. Underlying input relation is safe to push down and has no local
conditions,
as local conditions need to be applied before aggregation.
b. All the aggregates, GROUP BY expressions are safe to push down.
foreign_grouping_ok() functions assesses it.
While checking for shippability, we build the target list which is passed to
the foreign server as fdw_scan_tlist. The target list contains
a. All the GROUP BY expressions
b. Shippable entries from the target list of upper relation
c. Var and Aggref nodes from non-shippable entries from the target list of
upper relation
d. Var and Aggref nodes from non-shippable HAVING conditions.
The shippable having conditions are sent to the foreign server as part of
the
HAVING clause of the remote SQL.
is_foreign_expr() function, now handles T_Aggref node. Aggregate is safe to
push down if,
a. Aggregate is a built-in aggregate
b. All its arguments are safe to push-down
c. Other expressions involved like aggorder, aggdistinct, aggfilter etc. are
safe to be pushed down.
Costing:
If use_foreign_estimate is true for input relation, like JOIN case, we use
EXPLAIN output to get the cost of query with aggregation/grouping on the
foreign server. If not we calculate the costs locally. Similar to core, we
use
get_agg_clause_costs() to get costs for aggregation and then using logic
similar to cost_agg() we calculate startup and total cost. Since we have no
idea which aggregation strategy will be used at foreign side, we add all
startup cost (startup cost of input relation, aggregates etc.) into startup
cost for the grouping path and similarly for total cost.
Deparsing the query:
Target list created while checking for shippability is deparsed using
deparseExplicitTargetList(). sortgroupref are adjusted according to this
target list. Most of the logic to deparse an Aggref is inspired from
get_agg_expr(). For an upper relation, FROM and WHERE clauses come from the
underlying scan relation and thus for simplicity, FROM clause deparsing
logic
is moved from deparseSelectSql() to a new function deparseFromClause(). The
same function adds WHERE clause to the remote SQL.
Area of future work:
1. Adding path with path-keys to push ORDER BY clause along with
aggregation/
grouping. Should be supported as a separate patch.
2. Grouping Sets/Rollup/Cube is not supported in current version. I have
left
this aside to keep patch smaller. If required I can add that support in the
next version of the patch.
Most of the code in this patch is inspired from the JOIN push down code.
Ashutosh Bapat provided a high-level design and a skeleton patch to
start-with
offlist. Thanks to Tom Lane for his upper-planner pathification work and
adding
GetForeignUpperPaths callback function.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Phone: +91 20 30589500
Website: www.enterprisedb.com
EnterpriseDB Blog: http://blogs.enterprisedb.com/
Follow us on Twitter: http://www.twitter.com/enterprisedb
This e-mail message (and any attachment) is intended for the use of the
individual or entity to whom it is addressed. This message contains
information from EnterpriseDB Corporation that may be privileged,
confidential, or exempt from disclosure under applicable law. If you are
not the intended recipient or authorized to receive this for the intended
recipient, any use, dissemination, distribution, retention, archiving, or
copying of this communication is strictly prohibited. If you have received
this e-mail in error, please notify the sender immediately by reply e-mail
and delete this message.
Attachments:
pg_agg_push_down_v1.patchtext/x-patch; charset=US-ASCII; name=pg_agg_push_down_v1.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..88b76ff 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -38,6 +38,7 @@
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/sysattr.h"
+#include "catalog/pg_aggregate.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_namespace.h"
#include "catalog/pg_operator.h"
@@ -47,6 +48,7 @@
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/plannodes.h"
+#include "nodes/print.h"
#include "optimizer/clauses.h"
#include "optimizer/prep.h"
#include "optimizer/tlist.h"
@@ -55,7 +57,9 @@
#include "utils/builtins.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
+#include "utils/ruleutils.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
/*
@@ -65,6 +69,7 @@ typedef struct foreign_glob_cxt
{
PlannerInfo *root; /* global planner state */
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ bool foragg; /* is in context of aggregate push down? */
} foreign_glob_cxt;
/*
@@ -159,6 +164,11 @@ static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context);
static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *joinrel, bool use_alias, List **params_list);
+static void deparseFromClause(List *remote_conds, deparse_expr_cxt *context);
+static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
+static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
+static void deparseAggOrderBy(List *orderList, List *targetList,
+ deparse_expr_cxt *context);
/*
@@ -183,7 +193,7 @@ classifyConditions(PlannerInfo *root,
{
RestrictInfo *ri = (RestrictInfo *) lfirst(lc);
- if (is_foreign_expr(root, baserel, ri->clause))
+ if (is_foreign_expr(root, baserel, ri->clause, false))
*remote_conds = lappend(*remote_conds, ri);
else
*local_conds = lappend(*local_conds, ri);
@@ -196,7 +206,8 @@ classifyConditions(PlannerInfo *root,
bool
is_foreign_expr(PlannerInfo *root,
RelOptInfo *baserel,
- Expr *expr)
+ Expr *expr,
+ bool foragg)
{
foreign_glob_cxt glob_cxt;
foreign_loc_cxt loc_cxt;
@@ -207,6 +218,7 @@ is_foreign_expr(PlannerInfo *root,
*/
glob_cxt.root = root;
glob_cxt.foreignrel = baserel;
+ glob_cxt.foragg = foragg;
loc_cxt.collation = InvalidOid;
loc_cxt.state = FDW_COLLATE_NONE;
if (!foreign_expr_walker((Node *) expr, &glob_cxt, &loc_cxt))
@@ -631,6 +643,113 @@ foreign_expr_walker(Node *node,
check_type = false;
}
break;
+ case T_Aggref:
+ {
+ Aggref *agg = (Aggref *) node;
+ ListCell *lc;
+
+ /*
+ * Aggregate is safe to pushdown if
+ * 1. It is a built-in aggregate
+ * 2. All its arguments are safe to push-down
+ * 3. Other expressions involved like aggorder, aggdistinct are
+ * safe to be pushed down.
+ */
+
+ /* Not safe to pushdown when not in grouping context */
+ if (!glob_cxt->foragg)
+ return false;
+
+ /* Aggregates other than simple one are non-pushable. */
+ if (agg->aggsplit != AGGSPLIT_SIMPLE)
+ return false;
+
+ /*
+ * If aggregate function used by the expression is not
+ * shippable, it can't be sent to remote because it might
+ * have incompatible semantics on remote side.
+ */
+ if (!is_shippable(agg->aggfnoid, ProcedureRelationId, fpinfo))
+ return false;
+
+ /* Recurse to input subexpressions. */
+ if (!foreign_expr_walker((Node *) agg->aggdirectargs,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ foreach(lc, agg->args)
+ {
+ Node *n = (Node *) lfirst(lc);
+
+ /* If TargetEntry, extract the expression from it */
+ if (IsA(n, TargetEntry))
+ {
+ TargetEntry *tle = (TargetEntry *) n;
+ n = (Node *) tle->expr;
+ }
+
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+
+ if (agg->aggorder)
+ {
+ /* Get a list of order by expressions from arg list. */
+ List *olist = get_sortgrouplist_exprs(agg->aggorder,
+ agg->args);
+ foreach (lc, olist)
+ {
+ Node *n = (Node *) lfirst(lc);
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+ }
+
+ if (agg->aggdistinct)
+ {
+ /* Get a list of distinct expressions from arg list. */
+ List *dlist = get_sortgrouplist_exprs(agg->aggdistinct,
+ agg->args);
+ foreach (lc, dlist)
+ {
+ Node *n = (Node *) lfirst(lc);
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+ }
+
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
+ if (agg->inputcollid == InvalidOid)
+ /* OK, inputs are all noncollatable */ ;
+ else if (inner_cxt.state != FDW_COLLATE_SAFE ||
+ agg->inputcollid != inner_cxt.collation)
+ return false;
+
+ /*
+ * Detect whether node is introducing a collation not derived
+ * from a foreign Var. (If so, we just mark it unsafe for now
+ * rather than immediately returning false, since the parent
+ * node might not care.)
+ */
+ collation = agg->aggcollid;
+ if (collation == InvalidOid)
+ state = FDW_COLLATE_NONE;
+ else if (inner_cxt.state == FDW_COLLATE_SAFE &&
+ collation == inner_cxt.collation)
+ state = FDW_COLLATE_SAFE;
+ else if (collation == DEFAULT_COLLATION_OID)
+ state = FDW_COLLATE_NONE;
+ else
+ state = FDW_COLLATE_UNSAFE;
+ }
+ break;
default:
/*
@@ -723,11 +842,26 @@ deparse_type_name(Oid type_oid, int32 typemod)
* foreign server for the given relation.
*/
List *
-build_tlist_to_deparse(RelOptInfo *foreignrel)
+build_tlist_to_deparse(PlannerInfo *root, RelOptInfo *foreignrel)
{
List *tlist = NIL;
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /* Add Vars and aggregates from local conditions */
+ tlist = add_to_flat_tlist(fpinfo->grouped_tlist,
+ pull_var_clause((Node *) fpinfo->local_conds,
+ PVC_INCLUDE_AGGREGATES));
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, ptarget);
+
+ return tlist;
+ }
+
/*
* We require columns specified in foreignrel->reltarget->exprs and those
* required for evaluating the local conditions.
@@ -769,27 +903,32 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
{
deparse_expr_cxt context;
- /* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
- rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* We handle all relations other than dead one. */
+ Assert(rel->reloptkind != RELOPT_DEADREL);
- /* Fill portions of context common to join and base relation */
+ /* Fill portions of context common to upper, join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
context.params_list = params_list;
- /* Construct SELECT clause and FROM clause */
+ /* Construct SELECT clause */
deparseSelectSql(tlist, retrieved_attrs, &context);
- /*
- * Construct WHERE clause
- */
- if (remote_conds)
+ /* Construct FROM clause */
+ deparseFromClause(remote_conds, &context);
+
+ if (rel->reloptkind == RELOPT_UPPER_REL)
{
- appendStringInfo(buf, " WHERE ");
- appendConditions(remote_conds, &context);
+ /* Append GROUP BY clause */
+ appendGroupByClause(tlist, &context);
+
+ /* Append HAVING clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " HAVING ");
+ appendConditions(remote_conds, &context);
+ }
}
/* Add ORDER BY clause if we found any useful pathkeys */
@@ -803,7 +942,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
/*
* Construct a simple SELECT statement that retrieves desired columns
* of the specified foreign table, and append it to "buf". The output
- * contains just "SELECT ... FROM ....".
+ * contains just "SELECT ... ".
*
* We also create an integer List of the columns being retrieved, which is
* returned to *retrieved_attrs.
@@ -824,7 +963,8 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -847,14 +987,54 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
+}
+
+/*
+ * Construct a FROM clause and WHERE clause, if any. And append it to "buf".
+ * The final output contains "SELECT ... FROM ... [WHERE ... ]".
+ *
+ * remote_conds is the list of WHERE clauses, NIL if none.
+ */
+static void
+deparseFromClause(List *remote_conds, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ RelOptInfo *foreignrel = context->foreignrel;
+ PlannerInfo *root = context->root;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
+ RelOptInfo *scan_rel = foreignrel;
/*
- * Construct FROM clause
+ * For aggregates the FROM clause will be build from underneath scan rel.
+ * WHERE clause conditions too taken from there.
*/
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+ scan_rel = fpinfo->outerrel;
+ context->foreignrel = scan_rel;
+ remote_conds = ofpinfo->remote_conds;
+ }
+
+ /* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, root, scan_rel,
+ foreignrel->reloptkind == RELOPT_UPPER_REL ? true :
+ (scan_rel->reloptkind == RELOPT_JOINREL),
context->params_list);
+
+ /* Construct WHERE clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " WHERE ");
+ appendConditions(remote_conds, context);
+ }
+
+ /* Restore context's foreignrel */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ context->foreignrel = foreignrel;
}
/*
@@ -1036,7 +1216,7 @@ deparseLockingClause(deparse_expr_cxt *context)
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
- * deparse both WHERE clauses and JOIN .. ON clauses.
+ * deparse WHERE clauses, JOIN .. ON clauses and HAVING clauses.
*/
static void
appendConditions(List *exprs, deparse_expr_cxt *context)
@@ -1126,22 +1306,15 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
foreach(lc, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
- Var *var;
/* Extract expression if TargetEntry node */
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
-
- /* We expect only Var nodes here */
- if (!IsA(var, Var))
- elog(ERROR, "non-Var not expected in target list");
if (i > 0)
appendStringInfoString(buf, ", ");
- deparseVar(var, context);
+ deparseExpr((Expr *) tle->expr, context);
*retrieved_attrs = lappend_int(*retrieved_attrs, i + 1);
-
i++;
}
@@ -1849,6 +2022,9 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
case T_ArrayExpr:
deparseArrayExpr((ArrayExpr *) node, context);
break;
+ case T_Aggref:
+ deparseAggref((Aggref *)node, context);
+ break;
default:
elog(ERROR, "unsupported expression type for deparse: %d",
(int) nodeTag(node));
@@ -1867,7 +2043,8 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL ||
+ context->foreignrel->reloptkind == RELOPT_UPPER_REL);
if (bms_is_member(node->varno, context->foreignrel->relids) &&
node->varlevelsup == 0)
@@ -2420,6 +2597,181 @@ deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context)
}
/*
+ * Deparse an Aggref node.
+ */
+static void
+deparseAggref(Aggref *node, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ HeapTuple proctup;
+ Form_pg_proc procform;
+ const char *proname;
+ bool use_variadic;
+
+ /* Only basic, non-split aggregation accepted. */
+ Assert(node->aggsplit == AGGSPLIT_SIMPLE);
+
+ /* Find aggregate name from aggfnoid which is a pg_proc entry */
+ proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->aggfnoid));
+ if (!HeapTupleIsValid(proctup))
+ elog(ERROR, "cache lookup failed for aggregate function %u",
+ node->aggfnoid);
+ procform = (Form_pg_proc) GETSTRUCT(proctup);
+
+ /* Check if need to print VARIADIC (cf. ruleutils.c) */
+ use_variadic = node->aggvariadic;
+
+ /* Print schema name only if it's not pg_catalog */
+ if (procform->pronamespace != PG_CATALOG_NAMESPACE)
+ {
+ const char *schemaname;
+
+ schemaname = get_namespace_name(procform->pronamespace);
+ appendStringInfo(buf, "%s.", quote_identifier(schemaname));
+ }
+
+ /* Deparse the aggregate function name ... */
+ proname = NameStr(procform->proname);
+ appendStringInfo(buf, "%s(", quote_identifier(proname));
+
+ ReleaseSysCache(proctup);
+
+ /* Add DISTINCT */
+ appendStringInfo(buf, "%s", (node->aggdistinct != NIL) ? "DISTINCT " : "");
+
+ if (AGGKIND_IS_ORDERED_SET(node->aggkind))
+ {
+ /* Add WITHIN GROUP (ORDER BY ..) */
+ ListCell *arg;
+
+ Assert(!node->aggvariadic);
+ Assert(node->aggorder != NIL);
+
+ foreach(arg, node->aggdirectargs)
+ deparseExpr((Expr *) lfirst(arg), context);
+
+ appendStringInfoString(buf, ") WITHIN GROUP (ORDER BY ");
+ deparseAggOrderBy(node->aggorder, node->args, context);
+ }
+ else
+ {
+ /* aggstar can be set only in zero-argument aggregates */
+ if (node->aggstar)
+ appendStringInfoChar(buf, '*');
+ else
+ {
+ ListCell *arg;
+ bool first = true;
+
+ /* ... and all the arguments */
+ foreach(arg, node->args)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(arg);
+ Node *n = (Node *) tle->expr;
+
+ if (tle->resjunk)
+ continue;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ /* Add VARIADIC */
+ if (use_variadic && lnext(arg) == NULL)
+ appendStringInfoString(buf, "VARIADIC ");
+
+ deparseExpr((Expr *) n, context);
+ }
+ }
+
+ /* Add ORDER BY */
+ if (node->aggorder != NIL)
+ {
+ appendStringInfoString(buf, " ORDER BY ");
+ deparseAggOrderBy(node->aggorder, node->args, context);
+ }
+ }
+
+ /* Add FILTER (WHERE ..) */
+ if (node->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ deparseExpr((Expr *) node->aggfilter, context);
+ }
+
+ appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Deparse ORDER BY within aggregate function.
+ */
+static void
+deparseAggOrderBy(List *orderList, List *targetList, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ ListCell *lc;
+ bool first = true;
+
+ foreach (lc, orderList)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Expr *expr;
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+ TargetEntry *tle;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ tle = get_sortgroupref_tle(srt->tleSortGroupRef, targetList);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Must force parens for other expressions */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+
+ sortcoltype = exprType((Node *) expr);
+ /* See whether operator is default < or > for datatype */
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ if (srt->sortop == typentry->lt_opr)
+ {
+ /* ASC is default, so emit nothing for it */
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ }
+ else if (srt->sortop == typentry->gt_opr)
+ {
+ appendStringInfoString(buf, " DESC");
+ /* DESC defaults to NULLS FIRST */
+ if (!srt->nulls_first)
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+ else
+ {
+ appendStringInfo(buf, " USING %s",
+ generate_operator_name(srt->sortop,
+ sortcoltype,
+ sortcoltype));
+ /* be specific to eliminate ambiguity */
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ else
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+ }
+}
+
+/*
* Print the representation of a parameter to be sent to the remote side.
*
* Note: we always label the Param's type explicitly rather than relying on
@@ -2464,6 +2816,54 @@ printRemotePlaceholder(Oid paramtype, int32 paramtypmod,
}
/*
+ * Deparse GROUP BY clause.
+ */
+static void
+appendGroupByClause(List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ Query *query = context->root->parse;
+
+ if (query->groupClause != NULL)
+ {
+ appendStringInfo(buf, " GROUP BY ");
+
+ if (query->groupingSets == NIL)
+ {
+ ListCell *lc;
+ bool first = true;
+
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+ Index ref = grp->tleSortGroupRef;
+ TargetEntry *tle;
+ Expr *expr;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Must force parens for other expressions */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+ }
+ }
+ }
+}
+
+/*
* Deparse ORDER BY clause according to the given pathkeys for given base
* relation. From given pathkeys expressions belonging entirely to the given
* base relation are obtained and deparsed.
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d97e694..6ba1895 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,14 +861,13 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
---------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
-(5 rows)
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
count
@@ -878,14 +877,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
----------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = c2))
-(5 rows)
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
count
@@ -937,14 +935,13 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
-----------------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
count
@@ -954,14 +951,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
count
@@ -4441,12 +4437,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
--------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+ QUERY PLAN
+--------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" r1 WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4485,12 +4481,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
---------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+ QUERY PLAN
+---------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" r1 WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
@@ -5881,3 +5877,1480 @@ AND ftoptions @> array['fetch_size=60000'];
(1 row)
ROLLBACK;
+-- Test Aggregate Push Down
+-- Both ft1 and ft2 are used to exercise cost estimates when
+-- use_remote_estimate is false and true respectively.
+-- A. Simple aggregates
+explain (verbose, costs off)
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(r1."C 1"), avg(r1."C 1"), min(r1.c2), max(r1."C 1"), stddev(r1.c2) FROM "S 1"."T 1" r1
+(4 rows)
+
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+ sum | avg | min | max | stddev
+--------+----------------------+-----+------+------------------
+ 423821 | 515.5973236009732360 | 1 | 1218 | 233.490919491320
+(1 row)
+
+select sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) from "S 1"."T 1";
+ sum | avg | min | max | stddev
+--------+----------------------+-----+------+------------------
+ 423821 | 515.5973236009732360 | 1 | 1218 | 233.490919491320
+(1 row)
+
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+ QUERY PLAN
+--------------------------------------------------------
+ Foreign Scan
+ Output: (((sum(c1)))::double precision * random())
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(r1."C 1") FROM "S 1"."T 1" r1
+(4 rows)
+
+explain (verbose, costs off)
+select count(c6) from ft1;
+ QUERY PLAN
+-------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(r1.c6) FROM "S 1"."T 1" r1
+(4 rows)
+
+select count(c6) from ft1;
+ count
+-------
+ 801
+(1 row)
+
+select count(c6) from "S 1"."T 1";
+ count
+-------
+ 801
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------
+ Aggregate
+ Output: sum(((c1)::double precision * random())), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT sum(r1."C 1") FROM "S 1"."T 1" r1 WHERE ((c2 < 5))
+(4 rows)
+
+select sum(c1) from ft2 where c2 < 5;
+ sum
+-------
+ 50711
+(1 row)
+
+select sum("C 1") from "S 1"."T 1" where c2 < 5;
+ sum
+-------
+ 50711
+(1 row)
+
+explain (verbose, costs off)
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ sum | avg
+---------+----------------------
+ 5010000 | 501.0000000000000000
+(1 row)
+
+select sum(t1."C 1"), avg(t1."C 1") from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ sum | avg
+---------+----------------------
+ 5010000 | 501.0000000000000000
+(1 row)
+
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT count(*) FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ count
+-------
+ 10000
+(1 row)
+
+select count(*) from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ count
+-------
+ 10000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Nested Loop
+ Join Filter: ((t1.c2)::double precision = ((t2.c2)::double precision * random()))
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft1 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(12 rows)
+
+-- B. Aggregates with GROUP BY
+explain (verbose, costs off)
+select c2, count(*) from ft1 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c2, (count(*))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, count(*) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(7 rows)
+
+select c2, count(*) from ft1 group by c2 order by 1;
+ c2 | count
+-----+-------
+ 1 | 99
+ 2 | 2
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+ 503 | 1
+ 507 | 2
+ 509 | 100
+ 608 | 100
+ 609 | 2
+ 708 | 2
+ 818 | 2
+(21 rows)
+
+select c2, count(*) from "S 1"."T 1" group by c2 order by 1;
+ c2 | count
+-----+-------
+ 1 | 99
+ 2 | 2
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+ 503 | 1
+ 507 | 2
+ 509 | 100
+ 608 | 100
+ 609 | 2
+ 708 | 2
+ 818 | 2
+(21 rows)
+
+explain (verbose, costs off)
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c1)), (length((c6)::text)), c6
+ Sort Key: (count(ft2.c1)), (length((ft2.c6)::text))
+ -> Foreign Scan
+ Output: (count(c1)), (length((c6)::text)), c6
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT count(r1."C 1"), length(r1.c6), r1.c6 FROM "S 1"."T 1" r1 GROUP BY r1.c6
+(7 rows)
+
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+ count | length
+-------+--------
+ 1 | 4
+ 21 |
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+(10 rows)
+
+select count("C 1"), length(c6) from "S 1"."T 1" group by c6 order by 1, 2;
+ count | length
+-------+--------
+ 1 | 4
+ 21 |
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+(10 rows)
+
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Sort Key: ((ft1.c2 / 2))
+ -> Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (r1.c2 / 2), (sum(r1.c2) * (r1.c2 / 2)) FROM "S 1"."T 1" r1 GROUP BY ((r1.c2 / 2))
+(7 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 4
+ 3 | 1800
+ 21 | 88200
+ 22 | 96800
+ 50 | 20100
+ 52 | 10816
+ 53 | 11236
+ 100 | 20100
+ 102 | 20808
+ 151 | 4575300
+ 201 | 162006
+ 203 | 8262100
+ 251 | 126253
+ 253 | 256542
+ 254 | 12928600
+ 304 | 18853472
+ 354 | 501264
+ 409 | 669124
+(19 rows)
+
+select c2/2, sum(c2) * (c2/2) from "S 1"."T 1" group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 4
+ 3 | 1800
+ 21 | 88200
+ 22 | 96800
+ 50 | 20100
+ 52 | 10816
+ 53 | 11236
+ 100 | 20100
+ 102 | 20808
+ 151 | 4575300
+ 201 | 162006
+ 203 | 8262100
+ 251 | 126253
+ 253 | 256542
+ 254 | 12928600
+ 304 | 18853472
+ 354 | 501264
+ 409 | 669124
+(19 rows)
+
+explain (verbose, costs off)
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Sort
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Sort Key: ft1.c2, (sum(ft1.c1))
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, sum(r1."C 1"), sqrt(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2, (sqrt(r1."C 1"))
+(9 rows)
+
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+--------
+ 822 | 199823
+(1 row)
+
+select count(a), sum(a) from (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2, sqrt("C 1") order by 1, 2) x;
+ count | sum
+-------+--------
+ 822 | 199823
+(1 row)
+
+-- Aggregate is still pushed down by taking random() out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c1)::double precision * random()), ((sum(c1) * c1)), c1
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum(r1."C 1") * r1."C 1"), r1."C 1" FROM "S 1"."T 1" r1 GROUP BY r1."C 1"
+(4 rows)
+
+--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select "C 1" * random(), sum("C 1") * "C 1" from "S 1"."T 1" group by "C 1";
+-- Aggregate is not pushed down as random() is part of group by expression
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+ QUERY PLAN
+--------------------------------------------------------------
+ HashAggregate
+ Output: (((c1)::double precision * random())), c2
+ Group Key: ((ft2.c1)::double precision * random()), ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: ((c1)::double precision * random()), c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+-- C. Aggregates with HAVING clause
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 500::numeric))
+(7 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 order by 1;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 500::numeric)) AND ((sum(r1."C 1") < 200000))
+(7 rows)
+
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 and sum("C 1") < 200000 order by c2;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Sort Key: ft1.c5, (count(ft1.c2))
+ -> Foreign Scan
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c5, count(r1.c2), sqrt(r1.c2) FROM "S 1"."T 1" r1 GROUP BY r1.c5, (sqrt(r1.c2)) HAVING ((sqrt(max(r1.c2)) < 2::double precision))
+(7 rows)
+
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Fri Jan 02 00:00:00 1970 | 1
+ Fri Jan 02 00:00:00 1970 | 9
+ Mon Jan 12 00:00:00 1970 | 10
+ Thu Jan 22 00:00:00 1970 | 10
+ Sun Feb 01 00:00:00 1970 | 10
+ Wed Feb 11 00:00:00 1970 | 10
+ Sat Feb 21 00:00:00 1970 | 10
+ Tue Mar 03 00:00:00 1970 | 10
+ Fri Mar 13 00:00:00 1970 | 10
+ Mon Mar 23 00:00:00 1970 | 10
+ Thu Apr 02 00:00:00 1970 | 10
+ | 1
+(12 rows)
+
+select c5, count(c2) from "S 1"."T 1" group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Fri Jan 02 00:00:00 1970 | 1
+ Fri Jan 02 00:00:00 1970 | 9
+ Mon Jan 12 00:00:00 1970 | 10
+ Thu Jan 22 00:00:00 1970 | 10
+ Sun Feb 01 00:00:00 1970 | 10
+ Wed Feb 11 00:00:00 1970 | 10
+ Sat Feb 21 00:00:00 1970 | 10
+ Tue Mar 03 00:00:00 1970 | 10
+ Fri Mar 13 00:00:00 1970 | 10
+ Mon Mar 23 00:00:00 1970 | 10
+ Thu Apr 02 00:00:00 1970 | 10
+ | 1
+(12 rows)
+
+-- Having clause with random() will be evaluated locally
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Filter: ((((sum(ft2.c1)))::double precision * random()) < '500000'::double precision)
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(8 rows)
+
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+ c2 | sum
+-----+-------
+ 1 | 49599
+ 2 | 1112
+ 6 | 50100
+ 42 | 50500
+ 44 | 49900
+ 100 | 2030
+ 101 | 2012
+ 104 | 2018
+ 106 | 2022
+ 201 | 1101
+ 204 | 1104
+ 303 | 49800
+ 403 | 2016
+ 407 | 50200
+ 503 | 1103
+ 507 | 2024
+ 509 | 50400
+ 608 | 50300
+ 609 | 2028
+ 708 | 2026
+ 818 | 2426
+(21 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 500000 order by c2;
+ c2 | sum
+-----+-------
+ 1 | 49599
+ 2 | 1112
+ 6 | 50100
+ 42 | 50500
+ 44 | 49900
+ 100 | 2030
+ 101 | 2012
+ 104 | 2018
+ 106 | 2022
+ 201 | 1101
+ 204 | 1104
+ 303 | 49800
+ 403 | 2016
+ 407 | 50200
+ 503 | 1103
+ 507 | 2024
+ 509 | 50400
+ 608 | 50300
+ 609 | 2028
+ 708 | 2026
+ 818 | 2426
+(21 rows)
+
+-- Having clause with random() will be evaluated locally, and other having qual is pushed
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
+ Filter: ((((avg(ft1.c1)))::double precision * random()) < '500'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c5, NULL::bigint, sqrt(r1.c2), avg(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c5, (sqrt(r1.c2)) HAVING ((avg(r1."C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ count
+-------
+ 39
+(1 row)
+
+select count(*) from (select c5, count("C 1") from "S 1"."T 1" group by c5, sqrt(c2) having avg("C 1") * random() < 500 and avg("C 1") < 500) x;
+ count
+-------
+ 39
+(1 row)
+
+-- D. ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+explain (verbose, costs off)
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c3))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+select array_agg("C 1" order by c3) from "S 1"."T 1" where c2 = 6 and "C 1" < 100;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Sort Key: (array_agg(ft2.c1 ORDER BY ft2.c1))
+ -> Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1."C 1"), r1.c2 FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) GROUP BY r1.c2
+(7 rows)
+
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+ {11,21,31,41,51,61,71,81,91}
+(9 rows)
+
+select array_agg("C 1" order by "C 1") from "S 1"."T 1" where "C 1" < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+ {11,21,31,41,51,61,71,81,91}
+(9 rows)
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 DESC)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1."C 1" DESC), r1.c2 FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY r1.c2
+(4 rows)
+
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {96,86,76,66,56,46,36,26,16,6}
+(1 row)
+
+select array_agg("C 1" order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+ array_agg
+--------------------------------
+ {96,86,76,66,56,46,36,26,16,6}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(r1.c5 ORDER BY r1."C 1" DESC) FROM "S 1"."T 1" r1 WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+select array_agg(c5 order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5))), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {4,3,2,1,0}
+ {NULL,3,2,1}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {4,3,2,1,0}
+ {NULL,3,2,1}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum((r1."C 1" % 3)), sum(DISTINCT (r1."C 1" % 3)) FILTER (WHERE ((r1."C 1" % 3) < 2)), r1.c2 FROM "S 1"."T 1" r1 WHERE ((c2 = 6)) GROUP BY r1.c2
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+select sum("C 1"%3), sum(distinct "C 1"%3) filter (where "C 1"%3 < 2), c2 from "S 1"."T 1" where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Unique
+ Output: (sum(c1)), c2
+ -> Sort
+ Output: (sum(c1)), c2
+ Sort Key: ft2.c2, (sum(ft2.c1))
+ -> Foreign Scan
+ Output: (sum(c1)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT sum(r1."C 1"), r1.c2 FROM "S 1"."T 1" r1 WHERE ((c2 < 6)) GROUP BY r1.c2
+(9 rows)
+
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+ sum | c2
+-------+----
+ 49599 | 1
+ 1112 | 2
+(2 rows)
+
+select distinct sum("C 1"), c2 from "S 1"."T 1" where c2 < 6 group by c2 order by c2;
+ sum | c2
+-------+----
+ 49599 | 1
+ 1112 | 2
+(2 rows)
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE (ft1.c1 < 100)))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(r1."C 1") FILTER (WHERE (r1."C 1" < 100)), r1.c2 FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 1
+ 450
+ 459
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+select sum("C 1") filter (where "C 1" < 100) from "S 1"."T 1" group by c2 order by 1 nulls last;
+ sum
+-----
+ 1
+ 450
+ 459
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(r1."C 1") FILTER (WHERE ((r1."C 1" < 100) AND (r1.c2 > 5))), r1.c2 FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 450
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+select sum("C 1") filter (where "C 1" < 100 and c2 > 5) from "S 1"."T 1" group by c2 order by 1 nulls last;
+ sum
+-----
+ 450
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft1 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((r1.c2 = 6) AND (r1."C 1" < 10))) FROM "S 1"."T 1" r1
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft1 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(r1."C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" r1 WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+select distinct (select count(t1."C 1") filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ HashAggregate
+ Output: sum(c1) FILTER (WHERE (((c1)::double precision * random()) < '100'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+explain (verbose, costs off)
+select percentile_disc(0.25) within group (order by c2) from ft1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (percentile_disc('0.25'::double precision) WITHIN GROUP (ORDER BY c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT percentile_disc(0.25::double precision) WITHIN GROUP (ORDER BY r1.c2) FROM "S 1"."T 1" r1
+(4 rows)
+
+select percentile_disc(0.25) within group (order by c2) from ft1;
+ percentile_disc
+-----------------
+ 42
+(1 row)
+
+select percentile_disc(0.25) within group (order by c2) from "S 1"."T 1";
+ percentile_disc
+-----------------
+ 42
+(1 row)
+
+explain (verbose, costs off)
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, percentile_cont(0.5::double precision) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 WHERE ((c2 < 10)) GROUP BY r1.c2
+(7 rows)
+
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 501
+ 2 | 556
+ 6 | 501
+(3 rows)
+
+select c2, percentile_cont(0.5) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 501
+ 2 | 556
+ 6 | 501
+(3 rows)
+
+-- Error from remote server
+explain (verbose, costs off)
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, percentile_cont(r1.c2) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(7 rows)
+
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+ERROR: percentile value 2 is not between 0 and 1
+CONTEXT: Remote SQL command: SELECT r1.c2, percentile_cont(r1.c2) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+select c2, percentile_cont(c2) within group (order by "C 1") from "S 1"."T 1" group by c2 order by c2;
+ERROR: percentile value 2 is not between 0 and 1
+explain (verbose, costs off)
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, percentile_cont((r1.c2 / 10::numeric)) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 WHERE ((c2 < 10)) GROUP BY r1.c2 HAVING ((percentile_cont((r1.c2 / 10::numeric)) WITHIN GROUP (ORDER BY (r1."C 1")) < 500::double precision))
+(7 rows)
+
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 109
+ 2 | 223
+(2 rows)
+
+select c2, percentile_cont(c2/10::numeric) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by "C 1") < 500 order by c2;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 109
+ 2 | 223
+(2 rows)
+
+explain (verbose, costs off)
+select rank('10'::varchar) within group (order by c6) from ft1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (rank('10'::character varying) WITHIN GROUP (ORDER BY c6))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT rank('10'::character varying) WITHIN GROUP (ORDER BY r1.c6) FROM "S 1"."T 1" r1
+(4 rows)
+
+select rank('10'::varchar) within group (order by c6) from ft1;
+ rank
+------
+ 202
+(1 row)
+
+select rank('10'::varchar) within group (order by c6) from "S 1"."T 1";
+ rank
+------
+ 202
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Add into extension
+ALTER EXTENSION postgres_fdw ADD FUNCTION least_accum(anyelement, variadic anyarray);
+ALTER EXTENSION postgres_fdw ADD AGGREGATE least_agg(variadic items anyarray);
+ALTER SERVER loopback OPTIONS (SET extensions 'postgres_fdw');
+-- Now aggregate with VARIADIC will be pushed
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, public.least_agg(VARIADIC ARRAY[r1."C 1"]) FROM "S 1"."T 1" r1 WHERE ((c2 < 100)) GROUP BY r1.c2
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 1 | 11
+ 2 | 1
+ 6 | 6
+ 42 | 10
+ 44 | 4
+(5 rows)
+
+select c2, least_agg("C 1") from "S 1"."T 1" where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 1 | 11
+ 2 | 1
+ 6 | 6
+ 42 | 10
+ 44 | 4
+(5 rows)
+
+-- E. Mix aggregate tests
+-- Clauses with random() will be evaluated locally, and other clauses are pushed
+explain (verbose, costs off)
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ((ft2.c2)::double precision * random()), (NULL::bigint), ft2.c2
+ Filter: ((((sum(ft2.c1)))::double precision * random()) < '100000'::double precision)
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT NULL::bigint, r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 50000::numeric))
+(7 rows)
+
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+ count
+-------
+ 21
+(1 row)
+
+select count(*) from (select c2 * random(), count("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 100000 and avg("C 1") < 50000) x;
+ count
+-------
+ 21
+(1 row)
+
+explain (verbose, costs off)
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (sum(c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, sum(r1.c2) FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING (((avg(r1.c2) + r1.c2) < 10::numeric))
+(7 rows)
+
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+ c2 | sum
+----+-----
+ 1 | 99
+ 2 | 4
+(2 rows)
+
+select c2, sum(c2) from "S 1"."T 1" group by c2 having avg(c2) + c2 < 10 order by c2;
+ c2 | sum
+----+-----
+ 1 | 99
+ 2 | 4
+(2 rows)
+
+-- Input rel to aggregate push down hook is not safe to pushdown and thus the aggregate cannot be pushed down to remote
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t2
+ Remote SQL: SELECT NULL FROM "S 1"."T 1"
+ -> Materialize
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(11 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2
+(20 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 1 | 1101
+ 1 | 1103
+ 1 | 1104
+ 2 | 1112
+ 2 | 2012
+ 2 | 2016
+ 2 | 2018
+ 2 | 2022
+ 2 | 2024
+ 2 | 2026
+ 2 | 2028
+ 2 | 2030
+ 2 | 2426
+ 99 | 49599
+ 100 | 49800
+ 100 | 49900
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(21 rows)
+
+select count(*), x.b from "S 1"."T 1", (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2) x where "S 1"."T 1".c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 1 | 1101
+ 1 | 1103
+ 1 | 1104
+ 2 | 1112
+ 2 | 2012
+ 2 | 2016
+ 2 | 2018
+ 2 | 2022
+ 2 | 2024
+ 2 | 2026
+ 2 | 2028
+ 2 | 2030
+ 2 | 2426
+ 99 | 49599
+ 100 | 49800
+ 100 | 49900
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(21 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+select avg(t1.c1), sum(t2.c1) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- F. Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select sum(c1) from ft1 group by rollup(c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+explain (verbose, costs off)
+select sum(c1) from ft1 group by cube(c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+explain (verbose, costs off)
+select sum(c1) from ft1 group by grouping sets(c2, c3);
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: sum(c1), c2, c3
+ Group Key: ft1.c2
+ Sort Key: ft1.c3
+ Group Key: ft1.c3
+ -> Foreign Scan on public.ft1
+ Output: c2, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(8 rows)
+
+explain (verbose, costs off)
+select sum(c1), grouping(c2) from ft1 group by c2;
+ QUERY PLAN
+-------------------------------------------------------
+ HashAggregate
+ Output: sum(c1), GROUPING(c2), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..c33916f 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -24,7 +24,9 @@
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "nodes/print.h"
#include "optimizer/cost.h"
+#include "optimizer/clauses.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
@@ -38,6 +40,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/sampling.h"
+#include "utils/selfuncs.h"
PG_MODULE_MAGIC;
@@ -343,6 +346,10 @@ static void postgresGetForeignJoinPaths(PlannerInfo *root,
JoinPathExtraData *extra);
static bool postgresRecheckForeignScan(ForeignScanState *node,
TupleTableSlot *slot);
+static void postgresGetForeignUpperPaths(PlannerInfo *root,
+ UpperRelationKind stage,
+ RelOptInfo *input_rel,
+ RelOptInfo *output_rel);
/*
* Helper functions
@@ -400,12 +407,15 @@ static void conversion_error_callback(void *arg);
static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel,
JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinPathExtraData *extra);
+static bool foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel);
static List *get_useful_pathkeys_for_relation(PlannerInfo *root,
RelOptInfo *rel);
static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel);
static void add_paths_with_pathkeys_for_rel(PlannerInfo *root, RelOptInfo *rel,
Path *epq_path);
-
+static void create_foreign_grouping_paths(PlannerInfo *root,
+ RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel);
/*
* Foreign-data wrapper handler function: return a struct with pointers
@@ -455,6 +465,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
/* Support functions for join push-down */
routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+ /* Support functions for upper relation push-down */
+ routine->GetForeignUpperPaths = postgresGetForeignUpperPaths;
+
PG_RETURN_POINTER(routine);
}
@@ -805,7 +818,7 @@ get_useful_pathkeys_for_relation(PlannerInfo *root, RelOptInfo *rel)
*/
if (pathkey_ec->ec_has_volatile ||
!(em_expr = find_em_expr_for_rel(pathkey_ec, rel)) ||
- !is_foreign_expr(root, rel, em_expr))
+ !is_foreign_expr(root, rel, em_expr, false))
{
query_pathkeys_ok = false;
break;
@@ -858,7 +871,7 @@ get_useful_pathkeys_for_relation(PlannerInfo *root, RelOptInfo *rel)
/* If no pushable expression for this rel, skip it. */
em_expr = find_em_expr_for_rel(cur_ec, rel);
- if (em_expr == NULL || !is_foreign_expr(root, rel, em_expr))
+ if (em_expr == NULL || !is_foreign_expr(root, rel, em_expr, false))
continue;
/* Looks like we can generate a pathkey, so let's do it. */
@@ -942,7 +955,7 @@ postgresGetForeignPaths(PlannerInfo *root,
continue;
/* See if it is safe to send to remote */
- if (!is_foreign_expr(root, baserel, rinfo->clause))
+ if (!is_foreign_expr(root, baserel, rinfo->clause, false))
continue;
/* Calculate required outer rels for the resulting path */
@@ -1018,7 +1031,7 @@ postgresGetForeignPaths(PlannerInfo *root,
continue;
/* See if it is safe to send to remote */
- if (!is_foreign_expr(root, baserel, rinfo->clause))
+ if (!is_foreign_expr(root, baserel, rinfo->clause, false))
continue;
/* Calculate required outer rels for the resulting path */
@@ -1120,7 +1133,7 @@ postgresGetForeignPlan(PlannerInfo *root,
* rel->baserestrictinfo + parameterization clauses through
* scan_clauses. For a join rel->baserestrictinfo is NIL and we are
* not considering parameterization right now, so there should be no
- * scan_clauses for a joinrel.
+ * scan_clauses for a joinrel and upper rel either.
*/
Assert(!scan_clauses);
}
@@ -1161,7 +1174,7 @@ postgresGetForeignPlan(PlannerInfo *root,
}
else if (list_member_ptr(fpinfo->local_conds, rinfo))
local_exprs = lappend(local_exprs, rinfo->clause);
- else if (is_foreign_expr(root, foreignrel, rinfo->clause))
+ else if (is_foreign_expr(root, foreignrel, rinfo->clause, false))
{
remote_conds = lappend(remote_conds, rinfo);
remote_exprs = lappend(remote_exprs, rinfo->clause);
@@ -1177,7 +1190,7 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = fpinfo->local_conds;
/* Build the list of columns to be fetched from the foreign server. */
- fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
+ fdw_scan_tlist = build_tlist_to_deparse(root, foreignrel);
/*
* Ensure that the outer plan produces a tuple whose descriptor
@@ -1210,6 +1223,17 @@ postgresGetForeignPlan(PlannerInfo *root,
}
}
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ /*
+ * For a grouping relation, get the conditions from fdw_private
+ * structure.
+ */
+ remote_conds = fpinfo->remote_conds;
+ local_exprs = fpinfo->local_conds;
+
+ fdw_scan_tlist = build_tlist_to_deparse(root, foreignrel);
+ }
/*
* Build the query string to be sent for execution, and identify
@@ -1228,7 +1252,8 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2151,7 +2176,7 @@ postgresPlanDirectModify(PlannerInfo *root,
elog(ERROR, "attribute number %d not found in subplan targetlist",
attno);
- if (!is_foreign_expr(root, baserel, (Expr *) tle->expr))
+ if (!is_foreign_expr(root, baserel, (Expr *) tle->expr, false))
return false;
targetAttrs = lappend_int(targetAttrs, attno);
@@ -2452,7 +2477,8 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
/*
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
- * either a base relation or a join between foreign relations.
+ * either a base relation or a join between foreign relations or an upper
+ * relation.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -2505,8 +2531,9 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
- fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
+ fdw_scan_tlist = build_tlist_to_deparse(root, foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,25 +2613,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
- {
- /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
- retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
-
- /*
- * Cost as though this were a seqscan, which is pessimistic. We
- * effectively imagine the local_conds are being evaluated
- * remotely, too.
- */
- startup_cost = 0;
- run_cost = 0;
- run_cost += seq_page_cost * foreignrel->pages;
-
- startup_cost += foreignrel->baserestrictcost.startup;
- cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
- run_cost += cpu_per_tuple * foreignrel->tuples;
- }
- else
+ else if (foreignrel->reloptkind == RELOPT_JOINREL)
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
@@ -2670,6 +2679,95 @@ estimate_path_cost_size(PlannerInfo *root,
run_cost += nrows * remote_conds_cost.per_tuple;
run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows;
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+ AggClauseCosts aggcosts;
+ double input_rows;
+ int numGroupCols;
+ double numGroups = 1;
+
+ /*
+ * This cost model is mixture of costing done for sorted and hashed
+ * aggregates in cost_agg(). We are not sure which strategy will
+ * be considered at remote side, thus for simplicity, we put all
+ * startup related costs in startup_cost and all finalization and
+ * run cost are added in total_cost.
+ *
+ * Also, core does not care about costing HAVING expressions and
+ * adding that to the costs. So similarly, here too we are not
+ * considering remote and local conditions for costing.
+ */
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /* Get rows and width from input rel */
+ input_rows = ofpinfo->rows;
+ width = ofpinfo->width;
+
+ /* Collect statistics about aggregates for estimating costs. */
+ MemSet(&aggcosts, 0, sizeof(AggClauseCosts));
+ if (root->parse->hasAggs)
+ {
+ get_agg_clause_costs(root, (Node *) fpinfo->grouped_tlist,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ get_agg_clause_costs(root, (Node *) root->parse->havingQual,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ }
+
+ /* Get number of grouping columns and possible number of groups */
+ numGroupCols = list_length(root->parse->groupClause);
+ numGroups = estimate_num_groups(root, fpinfo->grouped_exprs,
+ input_rows, NULL);
+
+ /*
+ * Number of rows expected from remote server will be same as that
+ * of number of groups.
+ */
+ rows = retrieved_rows = numGroups;
+
+ /*
+ * Startup cost includes:
+ * 1. Startup cost for underneath input relation
+ * 2. Cost of performing aggregation, per cost_agg()
+ * 3. Startup cost for PathTarget eval
+ */
+ startup_cost = ofpinfo->rel_startup_cost;
+ startup_cost += aggcosts.transCost.startup;
+ startup_cost += aggcosts.transCost.per_tuple * input_rows;
+ startup_cost += (cpu_operator_cost * numGroupCols) * input_rows;
+ startup_cost += ptarget->cost.startup;
+
+ /*
+ * Run time cost includes:
+ * 1. Run time cost of underneath input relation
+ * 2. Run time cost of performing aggregation, per cost_agg()
+ * 4. PathTarget eval cost for each output row
+ */
+ run_cost = ofpinfo->rel_total_cost - ofpinfo->rel_startup_cost;
+ run_cost += aggcosts.finalCost * numGroups;
+ run_cost += cpu_tuple_cost * numGroups;
+ run_cost += ptarget->cost.per_tuple * numGroups;
+ }
+ else
+ {
+ /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
+ retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
+
+ /*
+ * Cost as though this were a seqscan, which is pessimistic. We
+ * effectively imagine the local_conds are being evaluated
+ * remotely, too.
+ */
+ startup_cost = 0;
+ run_cost = 0;
+ run_cost += seq_page_cost * foreignrel->pages;
+
+ startup_cost += foreignrel->baserestrictcost.startup;
+ cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
+ run_cost += cpu_per_tuple * foreignrel->tuples;
+ }
/*
* Without remote estimates, we have no real way to estimate the cost
@@ -3997,7 +4095,7 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
{
Expr *expr = (Expr *) lfirst(lc);
- if (!is_foreign_expr(root, joinrel, expr))
+ if (!is_foreign_expr(root, joinrel, expr, false))
return false;
}
@@ -4036,7 +4134,7 @@ foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype,
{
Expr *expr = (Expr *) lfirst(lc);
- if (!is_foreign_expr(root, joinrel, expr))
+ if (!is_foreign_expr(root, joinrel, expr, false))
fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
else
fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
@@ -4343,6 +4441,310 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
}
/*
+ * Assess whether the aggregation, grouping and having operations can be pushed
+ * down to the foreign server. As a side effect, save information we obtain in
+ * this function to PgFdwRelationInfo passed in.
+ */
+static bool
+foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
+{
+ Query *query = root->parse;
+ PathTarget *grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) grouped_rel->fdw_private;
+ PgFdwRelationInfo *ofpinfo;
+ List *aggvars;
+ ListCell *lc;
+ int i;
+ List *tlist = NIL;
+
+ /* Grouping Sets are not pushable */
+ if (query->groupingSets)
+ return false;
+
+ /* Get the fpinfo of the outerrel */
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /*
+ * If underneath input relation has any local conditions, those conditions
+ * are required to be applied before performing aggregation. Hence the
+ * aggregate cannot be pushed down.
+ */
+ if (ofpinfo->local_conds)
+ return false;
+
+ /*
+ * Evaluate grouping targets and check whether they are safe to push down
+ * to the remote side. All GROUP BY expressions will be part of the
+ * grouping target and thus no need to evaluate it separately. While doing
+ * so, add required expressions into target list which can then be used to
+ * pass to remote server.
+ */
+ i = 0;
+ foreach(lc, grouping_target->exprs)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+ Index sgref = get_pathtarget_sortgroupref(grouping_target, i);
+ ListCell *l;
+
+ /* Check whether this expression is part of GROUP BY clause */
+ if (sgref && query->groupClause && query->groupingSets == NIL &&
+ get_sortgroupref_clause_noerr(sgref, query->groupClause) != NULL)
+ {
+ /* Expression matched with GROUP BY, check as is */
+ if (!is_foreign_expr(root, grouped_rel, expr, true))
+ return false;
+
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* If not GROUP BY ref, reset it as we are not pushing those */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
+
+ /* Check entire expression whether it is pushable or not */
+ if (is_foreign_expr(root, grouped_rel, expr, true))
+ {
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* Not matched exactly, pull the var with aggregates then */
+ aggvars = pull_var_clause((Node *) expr,
+ PVC_INCLUDE_AGGREGATES);
+
+ if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars,
+ true))
+ return false;
+
+ /*
+ * Add aggregates, if any, into tlist. Plain Var nodes pulled
+ * are already part of GROUP BY and thus no need to add them
+ * explicitly.
+ */
+ foreach(l, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(l);
+
+ if (IsA(expr, Aggref))
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ }
+ }
+
+ i++;
+ }
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, grouping_target);
+ /* Store generated targetlist */
+ fpinfo->grouped_tlist = tlist;
+ fpinfo->grouped_exprs = get_sortgrouplist_exprs(query->groupClause, tlist);
+
+ /*
+ * Classify the pushable and non-pushable having clauses and save them in
+ * remote_conds and local_conds of grouped_rel::fpinfo.
+ */
+ if (root->hasHavingQual && query->havingQual)
+ {
+ ListCell *lc;
+
+ /* Having quals must be safe to push down. */
+ foreach(lc, (List *) query->havingQual)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ if (!is_foreign_expr(root, grouped_rel, expr, true))
+ fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
+ else
+ fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
+ }
+ }
+
+ /* Safe to pushdown */
+ fpinfo->pushdown_safe = true;
+
+ /*
+ * If user is willing to estimate cost for a scan using EXPLAIN, he intends
+ * to estimate scans on that relation more accurately. Then, it makes sense
+ * to estimate the cost of the grouping on that relation more accurately
+ * using EXPLAIN.
+ */
+ fpinfo->use_remote_estimate = ofpinfo->use_remote_estimate;
+
+ /* Get user mapping */
+ if (fpinfo->use_remote_estimate)
+ fpinfo->user = ofpinfo->user;
+ else
+ fpinfo->user = NULL;
+
+ /* Get foreign server */
+ fpinfo->server = ofpinfo->server;
+
+ /* Copy startup and tuple cost as is from underneath input rel's fpinfo */
+ fpinfo->fdw_startup_cost = ofpinfo->fdw_startup_cost;
+ fpinfo->fdw_tuple_cost = ofpinfo->fdw_tuple_cost;
+
+ /*
+ * Set cached relation costs to some negative value, so that we can detect
+ * when they are set to some sensible costs, during one (usually the
+ * first) of the calls to estimate_path_cost_size().
+ */
+ fpinfo->rel_startup_cost = -1;
+ fpinfo->rel_total_cost = -1;
+
+ /* Set fetch size same as that of underneath input rel's fpinfo */
+ fpinfo->fetch_size = ofpinfo->fetch_size;
+
+ /*
+ * Set the string describing this grouped relation to be used in EXPLAIN
+ * output of corresponding ForeignScan.
+ */
+ fpinfo->relation_name = makeStringInfo();
+ appendStringInfo(fpinfo->relation_name, "Aggregate on (%s)",
+ ofpinfo->relation_name->data);
+
+ return true;
+}
+
+/*
+ * postgresGetForeignUpperPaths
+ * Add paths for post-join operations like aggregation, grouping etc. if
+ * corresponding operations are safe to push down.
+ *
+ * Right now, we only support aggregate, grouping and having clause pushdown.
+ */
+static void
+postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
+ RelOptInfo *input_rel, RelOptInfo *output_rel)
+{
+ PgFdwRelationInfo *fpinfo;
+
+ /* If input rel is not aware of fdw, simply return */
+ if (!input_rel->fdw_private)
+ return;
+
+ /*
+ * This should not happen normally. In case we have already added paths for
+ * this output rel, nothing to be done again.
+ */
+ if (output_rel->fdw_private)
+ return;
+
+ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+ fpinfo->pushdown_safe = false;
+ output_rel->fdw_private = fpinfo;
+
+ switch (stage)
+ {
+ case UPPERREL_GROUP_AGG:
+ return create_foreign_grouping_paths(root, input_rel, output_rel);
+ break;
+
+ default:
+ /* If it's anything else, we are not adding any foreign path. */
+ return;
+ }
+}
+
+/*
+ * create_foreign_grouping_paths
+ *
+ * Add foreign path for grouping and/or aggregation.
+ *
+ * input_rel contains the underneath scan rel
+ * grouped_rel is the rel for which paths need to be added
+ */
+static void
+create_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel)
+{
+ Query *parse = root->parse;
+ PgFdwRelationInfo *ifpinfo = input_rel->fdw_private;
+ PgFdwRelationInfo *fpinfo = grouped_rel->fdw_private;
+ ForeignPath *grouppath;
+ PathTarget *grouping_target;
+ double rows;
+ int width;
+ Cost startup_cost;
+ Cost total_cost;
+
+ /*
+ * If input rel is not safe to pushdown, we cannot do grouping and/or
+ * aggregation on it.
+ */
+ if (!ifpinfo || !ifpinfo->pushdown_safe)
+ return;
+
+ /* Nothing to be done, if there is no grouping or aggregation required. */
+ if (!parse->groupClause && !parse->groupingSets && !parse->hasAggs &&
+ !root->hasHavingQual)
+ return;
+
+ grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /*
+ * We need relids to deparse column references from target list.
+ * FIXME: Is this a correct place to copy relids from underneath input_rel
+ * to the grouped_rel for which we are adding a path here? Or this should
+ * have been already set by core itself?
+ */
+ grouped_rel->relids = input_rel->relids;
+
+ /* save the input_rel as outerrel in fpinfo */
+ fpinfo->outerrel = input_rel;
+
+ /*
+ * Copy foreign table, foreign server, user mapping, shippable extensions
+ * etc. details from underneath input relation's fpinfo.
+ */
+ fpinfo->table = ifpinfo->table;
+ fpinfo->server = ifpinfo->server;
+ fpinfo->user = ifpinfo->user;
+ fpinfo->shippable_extensions = ifpinfo->shippable_extensions;
+
+ /* Assess if it is safe to push down aggregation and grouping. */
+ if (!foreign_grouping_ok(root, grouped_rel))
+ return;
+
+ /* Estimate the cost of push down */
+ estimate_path_cost_size(root, grouped_rel, NIL, NIL, &rows,
+ &width, &startup_cost, &total_cost);
+
+ /* Now update this information in the joinrel */
+ grouped_rel->rows = rows;
+ grouped_rel->reltarget->width = width;
+ fpinfo->rows = rows;
+ fpinfo->width = width;
+ fpinfo->startup_cost = startup_cost;
+ fpinfo->total_cost = total_cost;
+
+ /* Create and add foreign path to the grouping relation. */
+ grouppath = create_foreignscan_path(root,
+ grouped_rel,
+ grouping_target,
+ rows,
+ startup_cost,
+ total_cost,
+ NIL, /* no pathkeys */
+ NULL, /* no required_outer */
+ NULL,
+ NULL); /* no fdw_private */
+
+ /* Add generated path into grouped_rel by add_path(). */
+ add_path(grouped_rel, (Path *) grouppath);
+
+ /*
+ * Do we want to create paths with pathkeys corresponding for
+ * root->query_pathkeys.
+ */
+
+ return;
+}
+
+/*
* Create a tuple from the specified row of the PGresult.
*
* rel is the local representation of the foreign table, attinmeta is
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 67126bc..1dd4072 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -92,6 +92,10 @@ typedef struct PgFdwRelationInfo
RelOptInfo *innerrel;
JoinType jointype;
List *joinclauses;
+
+ /* Grouping information */
+ List *grouped_tlist;
+ List *grouped_exprs;
} PgFdwRelationInfo;
/* in postgres_fdw.c */
@@ -123,7 +127,8 @@ extern void classifyConditions(PlannerInfo *root,
List **local_conds);
extern bool is_foreign_expr(PlannerInfo *root,
RelOptInfo *baserel,
- Expr *expr);
+ Expr *expr,
+ bool foragg);
extern void deparseInsertSql(StringInfo buf, PlannerInfo *root,
Index rtindex, Relation rel,
List *targetAttrs, bool doNothing, List *returningList,
@@ -155,7 +160,7 @@ extern void deparseAnalyzeSql(StringInfo buf, Relation rel,
List **retrieved_attrs);
extern void deparseStringLiteral(StringInfo buf, const char *val);
extern Expr *find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel);
-extern List *build_tlist_to_deparse(RelOptInfo *foreign_rel);
+extern List *build_tlist_to_deparse(PlannerInfo *root, RelOptInfo *foreignrel);
extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, List *tlist,
List *remote_conds, List *pathkeys,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f68e89..48aca7c 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -1356,3 +1356,276 @@ WHERE ftrelid = 'table30000'::regclass
AND ftoptions @> array['fetch_size=60000'];
ROLLBACK;
+
+
+-- Test Aggregate Push Down
+-- Both ft1 and ft2 are used to exercise cost estimates when
+-- use_remote_estimate is false and true respectively.
+
+-- A. Simple aggregates
+explain (verbose, costs off)
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+select sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) from "S 1"."T 1";
+
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+
+explain (verbose, costs off)
+select count(c6) from ft1;
+select count(c6) from ft1;
+select count(c6) from "S 1"."T 1";
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+select sum(c1) from ft2 where c2 < 5;
+select sum("C 1") from "S 1"."T 1" where c2 < 5;
+
+explain (verbose, costs off)
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select sum(t1."C 1"), avg(t1."C 1") from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+select count(*) from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
+
+
+-- B. Aggregates with GROUP BY
+explain (verbose, costs off)
+select c2, count(*) from ft1 group by c2 order by 1;
+select c2, count(*) from ft1 group by c2 order by 1;
+select c2, count(*) from "S 1"."T 1" group by c2 order by 1;
+
+explain (verbose, costs off)
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+select count("C 1"), length(c6) from "S 1"."T 1" group by c6 order by 1, 2;
+
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from "S 1"."T 1" group by c2/2 order by c2/2;
+
+explain (verbose, costs off)
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(a), sum(a) from (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2, sqrt("C 1") order by 1, 2) x;
+
+-- Aggregate is still pushed down by taking random() out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select "C 1" * random(), sum("C 1") * "C 1" from "S 1"."T 1" group by "C 1";
+
+-- Aggregate is not pushed down as random() is part of group by expression
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+
+
+-- C. Aggregates with HAVING clause
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 order by 1;
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 and sum("C 1") < 200000 order by c2;
+
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+select c5, count(c2) from "S 1"."T 1" group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+
+-- Having clause with random() will be evaluated locally
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 500000 order by c2;
+
+-- Having clause with random() will be evaluated locally, and other having qual is pushed
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+select count(*) from (select c5, count("C 1") from "S 1"."T 1" group by c5, sqrt(c2) having avg("C 1") * random() < 500 and avg("C 1") < 500) x;
+
+
+-- D. ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+explain (verbose, costs off)
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+select array_agg("C 1" order by c3) from "S 1"."T 1" where c2 = 6 and "C 1" < 100;
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+select array_agg("C 1" order by "C 1") from "S 1"."T 1" where "C 1" < 100 group by c2 order by 1;
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+select array_agg("C 1" order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 50;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum("C 1"%3), sum(distinct "C 1"%3) filter (where "C 1"%3 < 2), c2 from "S 1"."T 1" where c2 = 6 group by c2;
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+select distinct sum("C 1"), c2 from "S 1"."T 1" where c2 < 6 group by c2 order by c2;
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+select sum("C 1") filter (where "C 1" < 100) from "S 1"."T 1" group by c2 order by 1 nulls last;
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum("C 1") filter (where "C 1" < 100 and c2 > 5) from "S 1"."T 1" group by c2 order by 1 nulls last;
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(t1."C 1") filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+
+-- Aggregate not pushed down
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+
+explain (verbose, costs off)
+select percentile_disc(0.25) within group (order by c2) from ft1;
+select percentile_disc(0.25) within group (order by c2) from ft1;
+select percentile_disc(0.25) within group (order by c2) from "S 1"."T 1";
+
+explain (verbose, costs off)
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, percentile_cont(0.5) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+
+-- Error from remote server
+explain (verbose, costs off)
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+select c2, percentile_cont(c2) within group (order by "C 1") from "S 1"."T 1" group by c2 order by c2;
+
+explain (verbose, costs off)
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, percentile_cont(c2/10::numeric) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by "C 1") < 500 order by c2;
+
+explain (verbose, costs off)
+select rank('10'::varchar) within group (order by c6) from ft1;
+select rank('10'::varchar) within group (order by c6) from ft1;
+select rank('10'::varchar) within group (order by c6) from "S 1"."T 1";
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Add into extension
+ALTER EXTENSION postgres_fdw ADD FUNCTION least_accum(anyelement, variadic anyarray);
+ALTER EXTENSION postgres_fdw ADD AGGREGATE least_agg(variadic items anyarray);
+ALTER SERVER loopback OPTIONS (SET extensions 'postgres_fdw');
+
+-- Now aggregate with VARIADIC will be pushed
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg("C 1") from "S 1"."T 1" where c2 < 100 group by c2 order by c2;
+
+
+-- E. Mix aggregate tests
+-- Clauses with random() will be evaluated locally, and other clauses are pushed
+explain (verbose, costs off)
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+select count(*) from (select c2 * random(), count("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 100000 and avg("C 1") < 50000) x;
+
+explain (verbose, costs off)
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+select c2, sum(c2) from "S 1"."T 1" group by c2 having avg(c2) + c2 < 10 order by c2;
+
+-- Input rel to aggregate push down hook is not safe to pushdown and thus the aggregate cannot be pushed down to remote
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from "S 1"."T 1", (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2) x where "S 1"."T 1".c2 = x.a group by x.b order by 1, 2;
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+select avg(t1.c1), sum(t2.c1) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+
+
+-- F. Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select sum(c1) from ft1 group by rollup(c2);
+explain (verbose, costs off)
+select sum(c1) from ft1 group by cube(c2);
+explain (verbose, costs off)
+select sum(c1) from ft1 group by grouping sets(c2, c3);
+explain (verbose, costs off)
+select sum(c1), grouping(c2) from ft1 group by c2;
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 47158f6..268518e 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -72,7 +72,6 @@ static Plan *create_plan_recurse(PlannerInfo *root, Path *best_path,
int flags);
static Plan *create_scan_plan(PlannerInfo *root, Path *best_path,
int flags);
-static List *build_path_tlist(PlannerInfo *root, Path *path);
static bool use_physical_tlist(PlannerInfo *root, Path *path, int flags);
static List *get_gating_quals(PlannerInfo *root, List *quals);
static Plan *create_gating_plan(PlannerInfo *root, Path *path, Plan *plan,
@@ -689,7 +688,7 @@ create_scan_plan(PlannerInfo *root, Path *best_path, int flags)
* This is almost just make_tlist_from_pathtarget(), but we also have to
* deal with replacing nestloop params.
*/
-static List *
+List *
build_path_tlist(PlannerInfo *root, Path *path)
{
List *tlist = NIL;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 8a81d7a..e8a3956 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -447,7 +447,6 @@ static char *generate_function_name(Oid funcid, int nargs,
List *argnames, Oid *argtypes,
bool has_variadic, bool *use_variadic_p,
ParseExprKind special_exprkind);
-static char *generate_operator_name(Oid operid, Oid arg1, Oid arg2);
static text *string_to_text(char *str);
static char *flatten_reloptions(Oid relid);
@@ -10041,7 +10040,7 @@ generate_function_name(Oid funcid, int nargs, List *argnames, Oid *argtypes,
* plus the OPERATOR() decoration needed to use a qualified operator name
* in an expression.
*/
-static char *
+char *
generate_operator_name(Oid operid, Oid arg1, Oid arg2)
{
StringInfoData buf;
diff --git a/src/include/optimizer/tlist.h b/src/include/optimizer/tlist.h
index 0d745a0..91e7d32 100644
--- a/src/include/optimizer/tlist.h
+++ b/src/include/optimizer/tlist.h
@@ -61,6 +61,7 @@ extern void add_column_to_pathtarget(PathTarget *target,
extern void add_new_column_to_pathtarget(PathTarget *target, Expr *expr);
extern void add_new_columns_to_pathtarget(PathTarget *target, List *exprs);
extern void apply_pathtarget_labeling_to_tlist(List *tlist, PathTarget *target);
+extern List *build_path_tlist(PlannerInfo *root, Path *path);
/* Convenience macro to get a PathTarget with valid cost/width fields */
#define create_pathtarget(root, tlist) \
diff --git a/src/include/utils/ruleutils.h b/src/include/utils/ruleutils.h
index cec2418..d6c6b8e 100644
--- a/src/include/utils/ruleutils.h
+++ b/src/include/utils/ruleutils.h
@@ -31,5 +31,6 @@ extern List *set_deparse_context_planstate(List *dpcontext,
extern List *select_rtable_names_for_explain(List *rtable,
Bitmapset *rels_used);
extern char *generate_collation_name(Oid collid);
+extern char *generate_operator_name(Oid operid, Oid arg1, Oid arg2);
#endif /* RULEUTILS_H */
Hi
2016-08-30 15:02 GMT+02:00 Jeevan Chalke <jeevan.chalke@enterprisedb.com>:
Hi all,
Attached is the patch which adds support to push down aggregation and
grouping
to the foreign server for postgres_fdw. Performing aggregation on foreign
server results into fetching fewer rows from foreign side as compared to
fetching all the rows and aggregating/grouping locally. Performing
grouping on
foreign server may use indexes if available. So pushing down aggregates/
grouping on foreign server performs better than doing that locally.
(Attached
EXPLAIN output for few simple grouping queries, with and without push
down).
is it work without FDW too?. It can be pretty interesting too.
Regards
Pavel
Show quoted text
Here are the few details of the implementation
Creating Paths:
Implements the FDW hook GetForeignUpperPaths, which adds foreign scan path
to
the output relation when upper relation kind is UPPERREL_GROUP_AGG. This
path
represents the aggregation/grouping operations to be performed on the
foreign
server. We are able to push down aggregation/grouping if (implemented in
foreign_grouping_ok()),
a. Underlying input relation is safe to push down and has no local
conditions,
as local conditions need to be applied before aggregation.
b. All the aggregates, GROUP BY expressions are safe to push down.
foreign_grouping_ok() functions assesses it.While checking for shippability, we build the target list which is passed
to
the foreign server as fdw_scan_tlist. The target list contains
a. All the GROUP BY expressions
b. Shippable entries from the target list of upper relation
c. Var and Aggref nodes from non-shippable entries from the target list of
upper relation
d. Var and Aggref nodes from non-shippable HAVING conditions.The shippable having conditions are sent to the foreign server as part of
the
HAVING clause of the remote SQL.is_foreign_expr() function, now handles T_Aggref node. Aggregate is safe to
push down if,
a. Aggregate is a built-in aggregate
b. All its arguments are safe to push-down
c. Other expressions involved like aggorder, aggdistinct, aggfilter etc.
are
safe to be pushed down.Costing:
If use_foreign_estimate is true for input relation, like JOIN case, we use
EXPLAIN output to get the cost of query with aggregation/grouping on the
foreign server. If not we calculate the costs locally. Similar to core, we
use
get_agg_clause_costs() to get costs for aggregation and then using logic
similar to cost_agg() we calculate startup and total cost. Since we have no
idea which aggregation strategy will be used at foreign side, we add all
startup cost (startup cost of input relation, aggregates etc.) into startup
cost for the grouping path and similarly for total cost.Deparsing the query:
Target list created while checking for shippability is deparsed using
deparseExplicitTargetList(). sortgroupref are adjusted according to this
target list. Most of the logic to deparse an Aggref is inspired from
get_agg_expr(). For an upper relation, FROM and WHERE clauses come from the
underlying scan relation and thus for simplicity, FROM clause deparsing
logic
is moved from deparseSelectSql() to a new function deparseFromClause(). The
same function adds WHERE clause to the remote SQL.Area of future work:
1. Adding path with path-keys to push ORDER BY clause along with
aggregation/
grouping. Should be supported as a separate patch.2. Grouping Sets/Rollup/Cube is not supported in current version. I have
left
this aside to keep patch smaller. If required I can add that support in the
next version of the patch.Most of the code in this patch is inspired from the JOIN push down code.
Ashutosh Bapat provided a high-level design and a skeleton patch to
start-with
offlist. Thanks to Tom Lane for his upper-planner pathification work and
adding
GetForeignUpperPaths callback function.Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL CompanyPhone: +91 20 30589500
Website: www.enterprisedb.com
EnterpriseDB Blog: http://blogs.enterprisedb.com/
Follow us on Twitter: http://www.twitter.com/enterprisedbThis e-mail message (and any attachment) is intended for the use of the
individual or entity to whom it is addressed. This message contains
information from EnterpriseDB Corporation that may be privileged,
confidential, or exempt from disclosure under applicable law. If you are
not the intended recipient or authorized to receive this for the intended
recipient, any use, dissemination, distribution, retention, archiving, or
copying of this communication is strictly prohibited. If you have received
this e-mail in error, please notify the sender immediately by reply e-mail
and delete this message.--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Tue, Aug 30, 2016 at 6:51 PM, Pavel Stehule <pavel.stehule@gmail.com>
wrote:
Hi
2016-08-30 15:02 GMT+02:00 Jeevan Chalke <jeevan.chalke@enterprisedb.com>:
Hi all,
Attached is the patch which adds support to push down aggregation and
grouping
to the foreign server for postgres_fdw. Performing aggregation on foreign
server results into fetching fewer rows from foreign side as compared to
fetching all the rows and aggregating/grouping locally. Performing
grouping on
foreign server may use indexes if available. So pushing down aggregates/
grouping on foreign server performs better than doing that locally.
(Attached
EXPLAIN output for few simple grouping queries, with and without push
down).is it work without FDW too?. It can be pretty interesting too.
No. Aggrgate push down is supported through the GetForeignUpperPaths() hook
added for postgres_fdw. Thus it works only with postgres_fdw.
Do you mean whether this works with any extensions via implementing
create_upper_paths_hook() function?
The answer is No. This patch does not touch this hook.
Regards
Pavel
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
2016-08-31 8:17 GMT+02:00 Jeevan Chalke <jeevan.chalke@enterprisedb.com>:
On Tue, Aug 30, 2016 at 6:51 PM, Pavel Stehule <pavel.stehule@gmail.com>
wrote:Hi
2016-08-30 15:02 GMT+02:00 Jeevan Chalke <jeevan.chalke@enterprisedb.com>
:Hi all,
Attached is the patch which adds support to push down aggregation and
grouping
to the foreign server for postgres_fdw. Performing aggregation on foreign
server results into fetching fewer rows from foreign side as compared to
fetching all the rows and aggregating/grouping locally. Performing
grouping on
foreign server may use indexes if available. So pushing down aggregates/
grouping on foreign server performs better than doing that locally.
(Attached
EXPLAIN output for few simple grouping queries, with and without push
down).is it work without FDW too?. It can be pretty interesting too.
No. Aggrgate push down is supported through the GetForeignUpperPaths() hook
added for postgres_fdw. Thus it works only with postgres_fdw.Do you mean whether this works with any extensions via implementing
create_upper_paths_hook() function?
The answer is No. This patch does not touch this hook.
It is pity - lot of performance issues are related to this missing feature.
Regards
Pavel
Show quoted text
Regards
Pavel
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Wed, Aug 31, 2016 at 11:56 AM, Pavel Stehule <pavel.stehule@gmail.com> wrote:
It is pity - lot of performance issues are related to this missing feature.
I don't think you are being very clear about what feature you are
talking about. The feature that Jeevan has implemented is pushing
aggregates to the remote side when postgres_fdw is in use. The
feature you are talking about is evidently something else, but you
haven't really said what it is. Or not in a way that I can
understand.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
2016-08-31 9:00 GMT+02:00 Robert Haas <robertmhaas@gmail.com>:
On Wed, Aug 31, 2016 at 11:56 AM, Pavel Stehule <pavel.stehule@gmail.com>
wrote:It is pity - lot of performance issues are related to this missing
feature.
I don't think you are being very clear about what feature you are
talking about. The feature that Jeevan has implemented is pushing
aggregates to the remote side when postgres_fdw is in use. The
feature you are talking about is evidently something else, but you
haven't really said what it is. Or not in a way that I can
understand.
yes, It is not clear if FDW aggregate push down can be implemented together
with internal aggregate push down. Aggregate push down ~ try to aggregate
first when it is possible
Regards
Pavel
Show quoted text
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
On 2016/08/31 16:42, Pavel Stehule wrote:
2016-08-31 9:00 GMT+02:00 Robert Haas <robertmhaas@gmail.com>:
On Wed, Aug 31, 2016 at 11:56 AM, Pavel Stehule <pavel.stehule@gmail.com>
wrote:It is pity - lot of performance issues are related to this missing
feature.
I don't think you are being very clear about what feature you are
talking about. The feature that Jeevan has implemented is pushing
aggregates to the remote side when postgres_fdw is in use. The
feature you are talking about is evidently something else, but you
haven't really said what it is. Or not in a way that I can
understand.yes, It is not clear if FDW aggregate push down can be implemented together
with internal aggregate push down. Aggregate push down ~ try to aggregate
first when it is possible
What do you mean by "internal aggregate push down"? Partition-wise
aggregation? Aggregate/group by before join (something like [1]/messages/by-id/CAKJS1f9kw95K2pnCKAoPmNw==7fgjSjC-82cy1RB+-x-Jz0QHA@mail.gmail.com)? IIUC,
what Jeevan proposes in this thread is to implement the aggregate push
down API that is specific to FDWs in postgres_fdw. Any other push down
work would need to use different APIs and would need to separately
proposed/discussed.
Thanks,
Amit
[1]: /messages/by-id/CAKJS1f9kw95K2pnCKAoPmNw==7fgjSjC-82cy1RB+-x-Jz0QHA@mail.gmail.com
/messages/by-id/CAKJS1f9kw95K2pnCKAoPmNw==7fgjSjC-82cy1RB+-x-Jz0QHA@mail.gmail.com
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
2016-08-31 10:03 GMT+02:00 Amit Langote <Langote_Amit_f8@lab.ntt.co.jp>:
On 2016/08/31 16:42, Pavel Stehule wrote:
2016-08-31 9:00 GMT+02:00 Robert Haas <robertmhaas@gmail.com>:
On Wed, Aug 31, 2016 at 11:56 AM, Pavel Stehule <
pavel.stehule@gmail.com>
wrote:
It is pity - lot of performance issues are related to this missing
feature.
I don't think you are being very clear about what feature you are
talking about. The feature that Jeevan has implemented is pushing
aggregates to the remote side when postgres_fdw is in use. The
feature you are talking about is evidently something else, but you
haven't really said what it is. Or not in a way that I can
understand.yes, It is not clear if FDW aggregate push down can be implemented
together
with internal aggregate push down. Aggregate push down ~ try to aggregate
first when it is possibleWhat do you mean by "internal aggregate push down"? Partition-wise
aggregation? Aggregate/group by before join (something like [1])? IIUC,
what Jeevan proposes in this thread is to implement the aggregate push
down API that is specific to FDWs in postgres_fdw. Any other push down
work would need to use different APIs and would need to separately
proposed/discussed.
ok I understand now.
Regards
Pavel
Show quoted text
Thanks,
Amit[1]
/messages/by-id/CAKJS1f9kw95K2pnCKAoPmNw==
7fgjSjC-82cy1RB+-x-Jz0QHA@mail.gmail.com
While checking for shippability, we build the target list which is passed
to
the foreign server as fdw_scan_tlist. The target list contains
a. All the GROUP BY expressions
b. Shippable entries from the target list of upper relation
c. Var and Aggref nodes from non-shippable entries from the target list of
upper relation
The code in the patch doesn't seem to add Var nodes explicitly. It assumes
that
the Var nodes will be part of GROUP BY clause. The code is correct, I think.
d. Var and Aggref nodes from non-shippable HAVING conditions.
This needs to be changed as per the comments below.
Costing:
If use_foreign_estimate is true for input relation, like JOIN case, we use
EXPLAIN output to get the cost of query with aggregation/grouping on the
foreign server. If not we calculate the costs locally. Similar to core, we
use
get_agg_clause_costs() to get costs for aggregation and then using logic
similar to cost_agg() we calculate startup and total cost. Since we have no
idea which aggregation strategy will be used at foreign side, we add all
startup cost (startup cost of input relation, aggregates etc.) into startup
cost for the grouping path and similarly for total cost.
This looks OK to me.
Deparsing the query:
Target list created while checking for shippability is deparsed using
deparseExplicitTargetList(). sortgroupref are adjusted according to this
target list. Most of the logic to deparse an Aggref is inspired from
get_agg_expr(). For an upper relation, FROM and WHERE clauses come from the
underlying scan relation and thus for simplicity, FROM clause deparsing
logic
is moved from deparseSelectSql() to a new function deparseFromClause(). The
same function adds WHERE clause to the remote SQL.
Ok.
Area of future work:
1. Adding path with path-keys to push ORDER BY clause along with
aggregation/
grouping. Should be supported as a separate patch.2. Grouping Sets/Rollup/Cube is not supported in current version. I have
left
this aside to keep patch smaller. If required I can add that support in the
next version of the patch.
I am fine with these limitations for first cut of this feature.
I think we should try to measure performance gain because of aggregate
pushdown. The EXPLAIN
doesn't show actual improvement in the execution times.
Here are the comments on the patch.
Patch compiles without errors/warnings - Yes
make check passes - Yes.
make check in contrib/postgres_fdw passes - Yes
Attached patch (based on your patch) has some typos corrected, some comments
rephrased. It also has some code changes, as explained in various comments
below. Please see if those look good.
1. Usually for any deparseSomething function, Something is the type of node
produced by the parser when the string output by that function is parsed.
deparseColumnRef, for example, produces a string, which when parsed
produces a
columnRef node. There is are nodes of type FromClause and AggOrderBy. I
guess,
you meant FromExpr instead of FromClause. deparseAggOrderBy() may be
renamed as
appendOrderByFromList() or something similar. It may be utilized for window
functions if required.
2. Can we infer the value of foragg flag from the RelOptInfo passed to
is_foreign_expr()? For any upper relation, it is ok to have aggregate in
there. For any other relation aggregate is not expected.
3. In function foreign_grouping_ok(), should we use classifyConditions()?
The
function is written and used for base relations. There's nothing in that
function, which prohibits it being used for other relations. I feel that
foreign_join_ok() should have used the same function to classify the other
clauses.
4. May be the individual criteria in the comment block
+ /*
+ * Aggregate is safe to pushdown if
+ * 1. It is a built-in aggregate
+ * 2. All its arguments are safe to push-down
+ * 3. The functions involved are immutable.
+ * 4. Other expressions involved like aggorder,
aggdistinct are
+ * safe to be pushed down.
+ */
should be associated with the code blocks which implement those. As the
criteria change it's difficult to maintain the numbered list in sync with
the
code.
5. The comment
+ /* Aggregates other than simple one are non-pushable. */
should read /* Only non-split aggregates are pushable. */ as AGGSPLIT_SIMPLE
means a complete, non-split aggregation step.
6. An aggregate function has transition, combination and finalization
function
associated with it. Should we check whether all of the functions are
shippable?
But probably it suffices to check whether aggregate function as whole is
shippable or not using is_shippable() since it's the whole aggregate we are
interested in and not the intermediate results. Probably, we should add a
comment explaining why it's sufficient to check the aggregate function as a
whole. I wondered whether we should check shippability of aggregate return
type, but we don't do that for functions as well. So it's fine.
7. It looks like aggdirectargs, aggdistinct, aggorder expressions are all
present in args list. If all the expressions in args are shippable, it means
those lists are also shippable and hence corresponding aggregate subclauses
are
shippable. Are we unnecessarily checking shippability of those other lists?
8. The prologue of build_tlist_to_deparse() mentions that the output
targetlist
contains columns, which is not true with your patch. The targetlist
returned by
this function can have expressions for upper relations. Please update the
prologue to reflect this change.
9. In build_tlist_to_deparse(), we are including aggregates from unshippable
conditions without checking whether they are shippable or not. This can
cause
an unshippable expression to be pushed to the foreign server as seen below
explain verbose select avg(c1) from ft1 having avg(c1 * random()) > 100;
QUERY
PLAN
--------------------------------------------------------------------------------------
Foreign Scan (cost=112.50..133.53 rows=1 width=32)
Output: (avg(c1))
Filter: ((avg(((ft1.c1)::double precision * random()))) > '100'::double
precision)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT avg(r1."C 1"), avg((r1."C 1" * random())) FROM "S
1"."T 1" r1
(5 rows)
We should check shippability of aggregates in unshippable conditions in
foreign_grouping_ok(). If any of those are not shippable, aggregation can
not
be pushed down. Otherwise, include those in the grouped_tlist.
10. Comment /* Construct FROM clause */ should read "Construct FROM and
WHERE
clauses." to be in sync with the next function call. deparseFromClause()
should
be renamed as deparseFromExpr() inline with the naming convention of
deparse<something> functions. From the function signature of
deparseFromClause(), it doesn't become clear as to what contributes to the
FROM
clause. Should we add a comment in the prologue of that function explaining
the
same. Also it strikes odd that for an upper relation, we pass remote_conds
to
this function, but it doesn't deparse those but deparses the remote
conditions
from the scan relation and later deparses the same remote_conds as HAVING
clause. Although this is correct, the code looks odd. May be the codeblock
in
deparseFuncClause()
1008 /*
1009 * For aggregates the FROM clause will be build from underneath
scan rel.
1010 * WHERE clause conditions too taken from there.
1011 */
1012 if (foreignrel->reloptkind == RELOPT_UPPER_REL)
1013 {
1014 PgFdwRelationInfo *ofpinfo;
1015
1016 ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
1017 scan_rel = fpinfo->outerrel;
1018 context->foreignrel = scan_rel;
1019 remote_conds = ofpinfo->remote_conds;
1020 }
should be moved into deparseSelectStmtForRel() to make the things clear.
11. Whether to qualify a column name by an alias should be based on whether
the
underlying scan relation is a join or base relation scan. That can be
achieved
by setting scanrel in the deparse_context. Attached patch has this
implemented.
Instead of scanrel, we may also have use_alias value as part of the context,
which is used everywhere.
12. The code to print the function name in deparseAggref() seems similar to
that in deparseFuncExpr(). Should we extract it out into a separate function
and call that function in deparseAggref() and deparseFuncExpr() both?
13. While deparsing the direct aggregates, the code is not adding ","
between
two arguments, resulting in error like below.
select rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2;
ERROR: syntax error at or near "c2"
CONTEXT: Remote SQL command: SELECT rank("C 1"c2) WITHIN GROUP (ORDER BY "C
1", c2), "C 1", c2 FROM "S 1"."T 1" GROUP BY "C 1", c2
May be we should add support to deparse List expressions by separating list
items by "," similar to get_rule_expr() and use that here.
14. In deparseAggOrderBy() we do not output anything for default cases like
ASC
or NULLS FIRST (for DESC). But like appendOrderByClause() it's better to be
explicit and output even the default specifications. That way, we do not
leave
anything to the interpretation of the foreign server.
15. deparseAggOrderBy supports deparsing USING subclause for ORDER BY for an
aggregate, but there is no corresponding shippability check for ordering
operator. Also, we should try to produce a testcase for the same.
16. The code to deparse a sort/group reference in deparseAggOrderBy() and
appendGroupByClause() looks similar. Should we extract it out into a
function
by itself and call that function in those two places similar to
get_rule_sortgroupclause()?
17. In postgresGetForeignPlan() the code to extract conditions and
targetlist
is duplicated for join and upper relation. Attached patch removes this
duplication. Since DML, FOR SHARE/UPDATE is not allowed with aggregation and
grouping, we should get an outer plan in that code.
18. estimate_path_cost_size() has grown quite long (~400 lines). Half of
that
function deals with estimating costs locally. Should we split this function
into smaller functions, one for estimating size and costs of each kind of
relations locally?
19. Condition below
+ if (sgref && query->groupClause && query->groupingSets == NIL &&
+ get_sortgroupref_clause_noerr(sgref, query->groupClause) !=
NULL)
can be rewritten as
if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause))
since we won't come here with non-NULL query->groupingSets and
get_sortgroupref_clause_noerr() will return NULL, if there aren't any
groupClause.
20. Please use word "foreign" instead of "remote" in comments.
21. This code looks dubious
+ /* If not GROUP BY ref, reset it as we are not pushing those */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
grouping_target comes from RelOptInfo, which is being modified here. We
shouldn't be modifying anything in the RelOptInfo while checking whether the
aggregate/grouping is shippable. You may want to copy the pathtaget and
modify
the copy.
22. Following comment needs more elaboration.
+ /*
+ * Add aggregates, if any, into tlist. Plain Var nodes
pulled
+ * are already part of GROUP BY and thus no need to add
them
+ * explicitly.
+ */
Plain Var nodes will either be same as some GROUP BY expression or should be
part of some GROUP BY expression. In the later case, the query can not refer
those without the surrounding expression. which will be part of the
targetlist
list. Hence we don't need to add plain Var nodes in the targetlist. In fact
adding those in SELECT clause will cause error on the foreign server if they
are not part of GROUP BY clause.
23. Probably you don't need to save this in fpinfo. You may want to
calculate
it whenever it's needed.
+ fpinfo->grouped_exprs = get_sortgrouplist_exprs(query->groupClause,
tlist);
24. Can this ever happen for postgres_fdw? The core sets fdwroutine and
calls
this function when the underlying scan relation has fdwroutine set, which
implies that it called corresponding GetForeignPath hooks, which should have
set fdw_private. Nonetheless, I think, still the condition is useful to
avoid
crashing the server in case the fdw_private is not set. But we need better
comments.
+ /* If input rel is not aware of fdw, simply return */
+ if (!input_rel->fdw_private)
+ return;
25. Although it's desirable to get a switch case in
postgresGetForeignUpperPaths() eventually, for this patch I guess we should
have an if condition there.
26. Attached patch has restructured code in appendGroupByClause() to reduce
indentation and make the code readable. Let me know if this looks good to
you.
27. Prologue of create_foreign_grouping_paths() does not have formatting
similar to the surrounding functions. Please fix it. Since the function
"create"s and "add"s paths, it might be better to rename it as
add_foreign_grouping_paths().
28. Isn't the following true for any upper relation and shouldn't it be
part of
postgresGetForeignUpperPaths(), rather than create_foreign_grouping_paths()?
+ /*
+ * If input rel is not safe to pushdown, we cannot do grouping and/or
+ * aggregation on it.
+ */
+ if (!ifpinfo || !ifpinfo->pushdown_safe)
+ return;
29. We require RelOptInfo::relids since create_foreignscan_plan() copies
them
into ForeignPlan::fs_relids and executor uses them. So, I guess, we have to
set
those in the core somewhere. May be while calling fetch_upper_rel() in
grouping_planner(), we should call it with relids of the underlying scan
relation. I don't see any function calling fetch_upper_rel() with non-NULL
relids. In fact, if we are to create an upper relation with relids in
future,
this code is going to wipe that out, which will be undesirable. Also,
generally, when copying relids, it's better to use bms_copy() to make a copy
of Bitmapset, instead of just assigning the pointer.
30. By the time postgresGetForeignUpperPaths() gets called, the core has
already added its own paths, so it doesn't make much sense to set rows and
width grouped_rel in create_foreign_grouping_paths().
31. fpinfo->server and user fields are being set twice, once in
create_foreign_grouping_paths() then in foreign_grouping_ok(). Do we need
that?
32.
+ /*
+ * Do we want to create paths with pathkeys corresponding for
+ * root->query_pathkeys.
+ */
Yes, it would be desirable to do that. If we are not going to do that in
this
patch, may be remove that line or add a TODO kind of comment.
33. The patch marks build_path_tlist() as non-static but does not use it
anywhere outside creatplan.c. Is this change intentional?
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_agg_pushdown_v1_extras.patchtext/x-patch; charset=US-ASCII; name=pg_agg_pushdown_v1_extras.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 5c35414..92a82a0 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -98,7 +98,9 @@ typedef struct foreign_loc_cxt
typedef struct deparse_expr_cxt
{
PlannerInfo *root; /* global planner state */
+
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ RelOptInfo *scanrel; /* the underlying scan relation. */
StringInfo buf; /* output buffer to append to */
List **params_list; /* exprs that will become remote Params */
} deparse_expr_cxt;
@@ -903,6 +905,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *)rel->fdw_private;
/* We handle all relations other than dead one. */
Assert(rel->reloptkind != RELOPT_DEADREL);
@@ -911,6 +914,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
context.buf = buf;
context.root = root;
context.foreignrel = rel;
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ? fpinfo->outerrel : rel;
context.params_list = params_list;
/* Construct SELECT clause */
@@ -991,10 +995,11 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
}
/*
- * Construct a FROM clause and WHERE clause, if any. And append it to "buf".
- * The final output contains "SELECT ... FROM ... [WHERE ... ]".
+ * Construct a FROM clause and a WHERE clause, if any, and append those to
+ * "buf".
*
- * remote_conds is the list of WHERE clauses, NIL if none.
+ * remote_conds is the list of clauses to be included in the WHERE clause,
+ * NIL if none.
*/
static void
deparseFromClause(List *remote_conds, deparse_expr_cxt *context)
@@ -1003,26 +1008,23 @@ deparseFromClause(List *remote_conds, deparse_expr_cxt *context)
RelOptInfo *foreignrel = context->foreignrel;
PlannerInfo *root = context->root;
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
- RelOptInfo *scan_rel = foreignrel;
+ RelOptInfo *scan_rel = context->scanrel;
/*
- * For aggregates the FROM clause will be build from underneath scan rel.
- * WHERE clause conditions too taken from there.
+ * For aggregates the FROM clause will be built from the underneath scan
+ * relation. Conditions in the WHERE clause are also taken from there.
*/
if (foreignrel->reloptkind == RELOPT_UPPER_REL)
{
PgFdwRelationInfo *ofpinfo;
ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
- scan_rel = fpinfo->outerrel;
- context->foreignrel = scan_rel;
remote_conds = ofpinfo->remote_conds;
}
/* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
deparseFromExprForRel(buf, root, scan_rel,
- foreignrel->reloptkind == RELOPT_UPPER_REL ? true :
(scan_rel->reloptkind == RELOPT_JOINREL),
context->params_list);
@@ -1032,10 +1034,6 @@ deparseFromClause(List *remote_conds, deparse_expr_cxt *context)
appendStringInfo(buf, " WHERE ");
appendConditions(remote_conds, context);
}
-
- /* Restore context's foreignrel */
- if (foreignrel->reloptkind == RELOPT_UPPER_REL)
- context->foreignrel = foreignrel;
}
/*
@@ -1138,14 +1136,14 @@ deparseTargetList(StringInfo buf,
/*
* Deparse the appropriate locking clause (FOR UPDATE or FOR SHARE) for a
- * given relation (context->foreignrel).
+ * given relation (context->scanrel).
*/
static void
deparseLockingClause(deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
PlannerInfo *root = context->root;
- RelOptInfo *rel = context->foreignrel;
+ RelOptInfo *rel = context->scanrel;
int relid = -1;
while ((relid = bms_next_member(rel->relids, relid)) >= 0)
@@ -1366,6 +1364,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
context.buf = buf;
context.foreignrel = foreignrel;
+ context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
@@ -1534,6 +1533,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1618,6 +1618,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -2044,10 +2045,10 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL ||
- context->foreignrel->reloptkind == RELOPT_UPPER_REL);
+ bool qualify_col = (context->scanrel->reloptkind == RELOPT_JOINREL ||
+ context->scanrel->reloptkind == RELOPT_UPPER_REL);
- if (bms_is_member(node->varno, context->foreignrel->relids) &&
+ if (bms_is_member(node->varno, context->scanrel->relids) &&
node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
@@ -2824,42 +2825,45 @@ appendGroupByClause(List *tlist, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
Query *query = context->root->parse;
+ ListCell *lc;
+ bool first = true;
- if (query->groupClause != NULL)
- {
- appendStringInfo(buf, " GROUP BY ");
+ /* Nothing to be done, if there's no GROUP BY clause in the query. */
+ if (!query->groupClause)
+ return;
- if (query->groupingSets == NIL)
- {
- ListCell *lc;
- bool first = true;
+ appendStringInfo(buf, " GROUP BY ");
- foreach(lc, query->groupClause)
- {
- SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
- Index ref = grp->tleSortGroupRef;
- TargetEntry *tle;
- Expr *expr;
+ /*
+ * Queries with grouping sets are not pushed down, so we don't grouping
+ * sets here.
+ */
+ Assert(!query->groupingSets);
- if (!first)
- appendStringInfoString(buf, ", ");
- first = false;
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+ Index ref = grp->tleSortGroupRef;
+ TargetEntry *tle;
+ Expr *expr;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
- tle = get_sortgroupref_tle(ref, tlist);
- expr = tle->expr;
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
- if (expr && IsA(expr, Const))
- deparseConst((Const *) expr, context);
- else if (!expr || IsA(expr, Var))
- deparseExpr(expr, context);
- else
- {
- /* Must force parens for other expressions */
- appendStringInfoString(buf, "(");
- deparseExpr(expr, context);
- appendStringInfoString(buf, ")");
- }
- }
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Must force parens for other expressions */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
}
}
}
@@ -2875,7 +2879,7 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
ListCell *lcell;
int nestlevel;
char *delim = " ";
- RelOptInfo *baserel = context->foreignrel;
+ RelOptInfo *baserel = context->scanrel;
StringInfo buf = context->buf;
/* Make sure any constants in the exprs are printed portably */
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 6ba1895..8079071 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,12 +861,12 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
----------------------------------------------------------------------------------
+ QUERY PLAN
+---------------------------------------------------------------------------
Foreign Scan
Output: (count(c3))
Relations: Aggregate on (public.ft1 t1)
- Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = abs(c2)))
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
@@ -877,12 +877,12 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------
Foreign Scan
Output: (count(c3))
Relations: Aggregate on (public.ft1 t1)
- Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = c2))
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
@@ -935,12 +935,12 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
Foreign Scan
Output: (count(c3))
Relations: Aggregate on (public.ft1 t1)
- Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
@@ -951,12 +951,12 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
Foreign Scan
Output: (count(c3))
Relations: Aggregate on (public.ft1 t1)
- Remote SQL: SELECT count(r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" OPERATOR(public.===) c2))
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
@@ -4437,12 +4437,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
---------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------
Foreign Scan
Output: (count(*))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT count(*) FROM "S 1"."T 1" r1 WHERE ((c2 < 0))
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4481,12 +4481,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
----------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------
Foreign Scan
Output: (count(*))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT count(*) FROM "S 1"."T 1" r1 WHERE ((c2 >= 0))
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
@@ -5883,12 +5883,12 @@ ROLLBACK;
-- A. Simple aggregates
explain (verbose, costs off)
select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
- QUERY PLAN
------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
Foreign Scan
Output: (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT sum(r1."C 1"), avg(r1."C 1"), min(r1.c2), max(r1."C 1"), stddev(r1.c2) FROM "S 1"."T 1" r1
+ Remote SQL: SELECT sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) FROM "S 1"."T 1"
(4 rows)
select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
@@ -5905,22 +5905,22 @@ select sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) from "S 1"."T 1";
explain (verbose, costs off)
select sum(c1) * random() from ft1;
- QUERY PLAN
---------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------
Foreign Scan
Output: (((sum(c1)))::double precision * random())
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT sum(r1."C 1") FROM "S 1"."T 1" r1
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
(4 rows)
explain (verbose, costs off)
select count(c6) from ft1;
- QUERY PLAN
--------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------
Foreign Scan
Output: (count(c6))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT count(r1.c6) FROM "S 1"."T 1" r1
+ Remote SQL: SELECT count(c6) FROM "S 1"."T 1"
(4 rows)
select count(c6) from ft1;
@@ -5949,12 +5949,12 @@ select sum(c1 * random()), avg(c1) from ft1;
explain (verbose, costs off)
select sum(c1) from ft2 where c2 < 5;
- QUERY PLAN
--------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------
Foreign Scan
Output: (sum(c1))
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT sum(r1."C 1") FROM "S 1"."T 1" r1 WHERE ((c2 < 5))
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1" WHERE ((c2 < 5))
(4 rows)
select sum(c1) from ft2 where c2 < 5;
@@ -6035,15 +6035,15 @@ select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
-- B. Aggregates with GROUP BY
explain (verbose, costs off)
select c2, count(*) from ft1 group by c2 order by 1;
- QUERY PLAN
--------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------
Sort
Output: c2, (count(*))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (count(*))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, count(*) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT c2, count(*) FROM "S 1"."T 1" GROUP BY c2
(7 rows)
select c2, count(*) from ft1 group by c2 order by 1;
@@ -6100,15 +6100,15 @@ select c2, count(*) from "S 1"."T 1" group by c2 order by 1;
explain (verbose, costs off)
select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
- QUERY PLAN
------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------------------------
Sort
Output: (count(c1)), (length((c6)::text)), c6
Sort Key: (count(ft2.c1)), (length((ft2.c6)::text))
-> Foreign Scan
Output: (count(c1)), (length((c6)::text)), c6
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT count(r1."C 1"), length(r1.c6), r1.c6 FROM "S 1"."T 1" r1 GROUP BY r1.c6
+ Remote SQL: SELECT count("C 1"), length(c6), c6 FROM "S 1"."T 1" GROUP BY c6
(7 rows)
select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
@@ -6143,15 +6143,15 @@ select count("C 1"), length(c6) from "S 1"."T 1" group by c6 order by 1, 2;
explain (verbose, costs off)
select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
- QUERY PLAN
----------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
Sort
Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
Sort Key: ((ft1.c2 / 2))
-> Foreign Scan
Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT (r1.c2 / 2), (sum(r1.c2) * (r1.c2 / 2)) FROM "S 1"."T 1" r1 GROUP BY ((r1.c2 / 2))
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
(7 rows)
select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
@@ -6204,8 +6204,8 @@ select c2/2, sum(c2) * (c2/2) from "S 1"."T 1" group by c2/2 order by c2/2;
explain (verbose, costs off)
select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
Aggregate
Output: count(ft1.c2), sum(ft1.c2)
-> Sort
@@ -6214,7 +6214,7 @@ select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(
-> Foreign Scan
Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, sum(r1."C 1"), sqrt(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2, (sqrt(r1."C 1"))
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
(9 rows)
select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
@@ -6232,12 +6232,12 @@ select count(a), sum(a) from (select c2 a, sum("C 1") b from "S 1"."T 1" group b
-- Aggregate is still pushed down by taking random() out
explain (verbose, costs off)
select c1 * random(), sum(c1) * c1 from ft1 group by c1;
- QUERY PLAN
--------------------------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------------------
Foreign Scan
Output: ((c1)::double precision * random()), ((sum(c1) * c1)), c1
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT (sum(r1."C 1") * r1."C 1"), r1."C 1" FROM "S 1"."T 1" r1 GROUP BY r1."C 1"
+ Remote SQL: SELECT (sum("C 1") * "C 1"), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
(4 rows)
--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
@@ -6258,15 +6258,15 @@ select c1 * random() from ft2 group by c1 * random(), c2;
-- C. Aggregates with HAVING clause
explain (verbose, costs off)
select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (sum(c1))
Sort Key: ft2.c2
-> Foreign Scan
Output: c2, (sum(c1))
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 500::numeric))
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric))
(7 rows)
select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
@@ -6285,15 +6285,15 @@ select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 order
explain (verbose, costs off)
select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
- QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (sum(c1))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (sum(c1))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 500::numeric)) AND ((sum(r1."C 1") < 200000))
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 200000))
(7 rows)
select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
@@ -6312,15 +6312,15 @@ select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 and s
explain (verbose, costs off)
select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
- QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
Sort
Output: c5, (count(c2)), (sqrt((c2)::double precision))
Sort Key: ft1.c5, (count(ft1.c2))
-> Foreign Scan
Output: c5, (count(c2)), (sqrt((c2)::double precision))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c5, count(r1.c2), sqrt(r1.c2) FROM "S 1"."T 1" r1 GROUP BY r1.c5, (sqrt(r1.c2)) HAVING ((sqrt(max(r1.c2)) < 2::double precision))
+ Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) < 2::double precision))
(7 rows)
select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
@@ -6369,7 +6369,7 @@ select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order
Output: c2, (sum(c1))
Filter: ((((sum(ft2.c1)))::double precision * random()) < '500000'::double precision)
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
(8 rows)
select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
@@ -6427,15 +6427,15 @@ select c2, sum("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random()
-- Having clause with random() will be evaluated locally, and other having qual is pushed
explain (verbose, costs off)
select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------
Aggregate
Output: count(*)
-> Foreign Scan
Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
Filter: ((((avg(ft1.c1)))::double precision * random()) < '500'::double precision)
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c5, NULL::bigint, sqrt(r1.c2), avg(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c5, (sqrt(r1.c2)) HAVING ((avg(r1."C 1") < 500::numeric))
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
(7 rows)
select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
@@ -6453,12 +6453,12 @@ select count(*) from (select c5, count("C 1") from "S 1"."T 1" group by c5, sqrt
-- D. ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
explain (verbose, costs off)
select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
Foreign Scan
Output: (array_agg(c1 ORDER BY c3))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1.c3) FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) AND ((c2 = 6))
+ Remote SQL: SELECT array_agg("C 1" ORDER BY c3) FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
(4 rows)
select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
@@ -6475,15 +6475,15 @@ select array_agg("C 1" order by c3) from "S 1"."T 1" where c2 = 6 and "C 1" < 10
explain (verbose, costs off)
select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------
Sort
Output: (array_agg(c1 ORDER BY c1)), c2
Sort Key: (array_agg(ft2.c1 ORDER BY ft2.c1))
-> Foreign Scan
Output: (array_agg(c1 ORDER BY c1)), c2
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1."C 1"), r1.c2 FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) GROUP BY r1.c2
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1"), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
(7 rows)
select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
@@ -6516,12 +6516,12 @@ select array_agg("C 1" order by "C 1") from "S 1"."T 1" where "C 1" < 100 group
explain (verbose, costs off)
select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: (array_agg(c1 ORDER BY c1 DESC)), c2
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT array_agg(r1."C 1" ORDER BY r1."C 1" DESC), r1.c2 FROM "S 1"."T 1" r1 WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY r1.c2
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" DESC), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
(4 rows)
select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
@@ -6538,12 +6538,12 @@ select array_agg("C 1" order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C
explain (verbose, costs off)
select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: (array_agg(c5 ORDER BY c1 DESC))
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT array_agg(r1.c5 ORDER BY r1."C 1" DESC) FROM "S 1"."T 1" r1 WHERE (("C 1" < 50)) AND ((c2 = 6))
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
(4 rows)
select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
@@ -6668,12 +6668,12 @@ select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from "S
explain (verbose, costs off)
select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
- QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT sum((r1."C 1" % 3)), sum(DISTINCT (r1."C 1" % 3)) FILTER (WHERE ((r1."C 1" % 3) < 2)), r1.c2 FROM "S 1"."T 1" r1 WHERE ((c2 = 6)) GROUP BY r1.c2
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3)) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
(4 rows)
select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
@@ -6691,8 +6691,8 @@ select sum("C 1"%3), sum(distinct "C 1"%3) filter (where "C 1"%3 < 2), c2 from "
-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
explain (verbose, costs off)
select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
- QUERY PLAN
------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
Unique
Output: (sum(c1)), c2
-> Sort
@@ -6701,7 +6701,7 @@ select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
-> Foreign Scan
Output: (sum(c1)), c2
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT sum(r1."C 1"), r1.c2 FROM "S 1"."T 1" r1 WHERE ((c2 < 6)) GROUP BY r1.c2
+ Remote SQL: SELECT sum("C 1"), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
(9 rows)
select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
@@ -6720,15 +6720,15 @@ select distinct sum("C 1"), c2 from "S 1"."T 1" where c2 < 6 group by c2 order b
explain (verbose, costs off)
select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
Sort
Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
Sort Key: (sum(ft1.c1) FILTER (WHERE (ft1.c1 < 100)))
-> Foreign Scan
Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT sum(r1."C 1") FILTER (WHERE (r1."C 1" < 100)), r1.c2 FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE ("C 1" < 100)), c2 FROM "S 1"."T 1" GROUP BY c2
(7 rows)
select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
@@ -6785,15 +6785,15 @@ select sum("C 1") filter (where "C 1" < 100) from "S 1"."T 1" group by c2 order
explain (verbose, costs off)
select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
Sort
Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
-> Foreign Scan
Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT sum(r1."C 1") FILTER (WHERE ((r1."C 1" < 100) AND (r1.c2 > 5))), r1.c2 FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
(7 rows)
select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
@@ -6851,8 +6851,8 @@ select sum("C 1") filter (where "C 1" < 100 and c2 > 5) from "S 1"."T 1" group b
-- Outer query is aggregation query
explain (verbose, costs off)
select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
Unique
Output: ((SubPlan 1))
-> Sort
@@ -6861,7 +6861,7 @@ select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft
-> Foreign Scan
Output: (SubPlan 1)
Relations: Aggregate on (public.ft1 t2)
- Remote SQL: SELECT count(*) FILTER (WHERE ((r1.c2 = 6) AND (r1."C 1" < 10))) FROM "S 1"."T 1" r1
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
SubPlan 1
-> Foreign Scan on public.ft1 t1
Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
@@ -6883,8 +6883,8 @@ select distinct (select count(*) filter (where t2.c2 = 6 and t2."C 1" < 10) from
-- Inner query is aggregation query
explain (verbose, costs off)
select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
Unique
Output: ((SubPlan 1))
-> Sort
@@ -6897,7 +6897,7 @@ select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) fro
-> Foreign Scan
Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
Relations: Aggregate on (public.ft1 t1)
- Remote SQL: SELECT count(r1."C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" r1 WHERE (("C 1" = 6))
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
(13 rows)
select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
@@ -6944,12 +6944,12 @@ select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
explain (verbose, costs off)
select percentile_disc(0.25) within group (order by c2) from ft1;
- QUERY PLAN
-----------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
Foreign Scan
Output: (percentile_disc('0.25'::double precision) WITHIN GROUP (ORDER BY c2))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT percentile_disc(0.25::double precision) WITHIN GROUP (ORDER BY r1.c2) FROM "S 1"."T 1" r1
+ Remote SQL: SELECT percentile_disc(0.25::double precision) WITHIN GROUP (ORDER BY c2) FROM "S 1"."T 1"
(4 rows)
select percentile_disc(0.25) within group (order by c2) from ft1;
@@ -6966,15 +6966,15 @@ select percentile_disc(0.25) within group (order by c2) from "S 1"."T 1";
explain (verbose, costs off)
select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, percentile_cont(0.5::double precision) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 WHERE ((c2 < 10)) GROUP BY r1.c2
+ Remote SQL: SELECT c2, percentile_cont(0.5::double precision) WITHIN GROUP (ORDER BY ("C 1")) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
(7 rows)
select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
@@ -6996,33 +6996,33 @@ select c2, percentile_cont(0.5) within group (order by "C 1") from "S 1"."T 1" w
-- Error from remote server
explain (verbose, costs off)
select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, percentile_cont(r1.c2) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT c2, percentile_cont(c2) WITHIN GROUP (ORDER BY ("C 1")) FROM "S 1"."T 1" GROUP BY c2
(7 rows)
select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
ERROR: percentile value 2 is not between 0 and 1
-CONTEXT: Remote SQL command: SELECT r1.c2, percentile_cont(r1.c2) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 GROUP BY r1.c2
+CONTEXT: Remote SQL command: SELECT c2, percentile_cont(c2) WITHIN GROUP (ORDER BY ("C 1")) FROM "S 1"."T 1" GROUP BY c2
select c2, percentile_cont(c2) within group (order by "C 1") from "S 1"."T 1" group by c2 order by c2;
ERROR: percentile value 2 is not between 0 and 1
explain (verbose, costs off)
select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
- QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, percentile_cont((r1.c2 / 10::numeric)) WITHIN GROUP (ORDER BY (r1."C 1")) FROM "S 1"."T 1" r1 WHERE ((c2 < 10)) GROUP BY r1.c2 HAVING ((percentile_cont((r1.c2 / 10::numeric)) WITHIN GROUP (ORDER BY (r1."C 1")) < 500::double precision))
+ Remote SQL: SELECT c2, percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1")) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1")) < 500::double precision))
(7 rows)
select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
@@ -7041,12 +7041,12 @@ select c2, percentile_cont(c2/10::numeric) within group (order by "C 1") from "S
explain (verbose, costs off)
select rank('10'::varchar) within group (order by c6) from ft1;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
Foreign Scan
Output: (rank('10'::character varying) WITHIN GROUP (ORDER BY c6))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT rank('10'::character varying) WITHIN GROUP (ORDER BY r1.c6) FROM "S 1"."T 1" r1
+ Remote SQL: SELECT rank('10'::character varying) WITHIN GROUP (ORDER BY c6) FROM "S 1"."T 1"
(4 rows)
select rank('10'::varchar) within group (order by c6) from ft1;
@@ -7091,15 +7091,15 @@ ALTER SERVER loopback OPTIONS (SET extensions 'postgres_fdw');
-- Now aggregate with VARIADIC will be pushed
explain (verbose, costs off)
select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (least_agg(VARIADIC ARRAY[c1]))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (least_agg(VARIADIC ARRAY[c1]))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, public.least_agg(VARIADIC ARRAY[r1."C 1"]) FROM "S 1"."T 1" r1 WHERE ((c2 < 100)) GROUP BY r1.c2
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
(7 rows)
select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
@@ -7126,15 +7126,15 @@ select c2, least_agg("C 1") from "S 1"."T 1" where c2 < 100 group by c2 order by
-- Clauses with random() will be evaluated locally, and other clauses are pushed
explain (verbose, costs off)
select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
Aggregate
Output: count(*)
-> Foreign Scan
Output: ((ft2.c2)::double precision * random()), (NULL::bigint), ft2.c2
Filter: ((((sum(ft2.c1)))::double precision * random()) < '100000'::double precision)
Relations: Aggregate on (public.ft2)
- Remote SQL: SELECT NULL::bigint, r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING ((avg(r1."C 1") < 50000::numeric))
+ Remote SQL: SELECT NULL::bigint, c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 50000::numeric))
(7 rows)
select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
@@ -7151,15 +7151,15 @@ select count(*) from (select c2 * random(), count("C 1") from "S 1"."T 1" group
explain (verbose, costs off)
select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
- QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
Sort
Output: c2, (sum(c2))
Sort Key: ft1.c2
-> Foreign Scan
Output: c2, (sum(c2))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, sum(r1.c2) FROM "S 1"."T 1" r1 GROUP BY r1.c2 HAVING (((avg(r1.c2) + r1.c2) < 10::numeric))
+ Remote SQL: SELECT c2, sum(c2) FROM "S 1"."T 1" GROUP BY c2 HAVING (((avg(c2) + c2) < 10::numeric))
(7 rows)
select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
@@ -7197,8 +7197,8 @@ select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
-- Subquery in FROM clause having aggregate
explain (verbose, costs off)
select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
Sort
Output: (count(*)), x.b
Sort Key: (count(*)), x.b
@@ -7218,7 +7218,7 @@ select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x w
-> Foreign Scan
Output: ft1_1.c2, (sum(ft1_1.c1))
Relations: Aggregate on (public.ft1)
- Remote SQL: SELECT r1.c2, sum(r1."C 1") FROM "S 1"."T 1" r1 GROUP BY r1.c2
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
(20 rows)
select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index c33916f..4dda273 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -1183,7 +1183,8 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1204,6 +1205,13 @@ postgresGetForeignPlan(PlannerInfo *root,
{
ListCell *lc;
+ /*
+ * Right now, we only consider grouping and aggregation beyond
+ * joins. Queries involving aggregates or grouping do not require
+ * EPQ mechanism, hence should not have an outer plan here.
+ */
+ Assert(foreignrel->reloptkind != RELOPT_UPPER_REL);
+
outer_plan->targetlist = fdw_scan_tlist;
foreach(lc, local_exprs)
@@ -1223,17 +1231,6 @@ postgresGetForeignPlan(PlannerInfo *root,
}
}
}
- else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
- {
- /*
- * For a grouping relation, get the conditions from fdw_private
- * structure.
- */
- remote_conds = fpinfo->remote_conds;
- local_exprs = fpinfo->local_conds;
-
- fdw_scan_tlist = build_tlist_to_deparse(root, foreignrel);
- }
/*
* Build the query string to be sent for execution, and identify
@@ -2478,7 +2475,7 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
* either a base relation or a join between foreign relations or an upper
- * relation.
+ * relation containing foreign relations.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -4443,7 +4440,7 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
/*
* Assess whether the aggregation, grouping and having operations can be pushed
* down to the foreign server. As a side effect, save information we obtain in
- * this function to PgFdwRelationInfo passed in.
+ * this function to PgFdwRelationInfo of the input relation.
*/
static bool
foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
@@ -4461,7 +4458,7 @@ foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
if (query->groupingSets)
return false;
- /* Get the fpinfo of the outerrel */
+ /* Get the fpinfo of the underlying scan relation. */
ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
/*
@@ -4474,10 +4471,10 @@ foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
/*
* Evaluate grouping targets and check whether they are safe to push down
- * to the remote side. All GROUP BY expressions will be part of the
- * grouping target and thus no need to evaluate it separately. While doing
- * so, add required expressions into target list which can then be used to
- * pass to remote server.
+ * to the foreign side. All GROUP BY expressions will be part of the
+ * grouping target and thus there is no need to evaluate it separately.
+ * While doing so, add required expressions into target list which
+ * can then be used to pass to foreign server.
*/
i = 0;
foreach(lc, grouping_target->exprs)
@@ -4490,7 +4487,10 @@ foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
if (sgref && query->groupClause && query->groupingSets == NIL &&
get_sortgroupref_clause_noerr(sgref, query->groupClause) != NULL)
{
- /* Expression matched with GROUP BY, check as is */
+ /*
+ * If any of the GROUP BY expression is not shippable we can not
+ * push down aggregation to the foreign server.
+ */
if (!is_foreign_expr(root, grouped_rel, expr, true))
return false;
@@ -4521,7 +4521,7 @@ foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
/*
* Add aggregates, if any, into tlist. Plain Var nodes pulled
- * are already part of GROUP BY and thus no need to add them
+ * are already part of some and thus no need to add them
* explicitly.
*/
foreach(l, aggvars)
@@ -4654,8 +4654,8 @@ postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
*
* Add foreign path for grouping and/or aggregation.
*
- * input_rel contains the underneath scan rel
- * grouped_rel is the rel for which paths need to be added
+ * input_rel represents the underlying scan. The paths are added to the
+ * grouped_rel.
*/
static void
create_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
Hi,
While testing "Aggregate pushdown", i found the below error:
-- GROUP BY alias showing different behavior after adding patch.
-- Create table "t1", insert few records.
create table t1(c1 int);
insert into t1 values(10), (20);
-- Create foreign table:
create foreign table f_t1 (c1 int) server db1_server options (table_name
't1');
-- with local table:
postgres=# select 2 a, avg(c1) from t1 group by a;
a | avg
---+---------------------
2 | 15.0000000000000000
(1 row)
-- with foreign table:
postgres=# select 2 a, avg(c1) from f_t1 group by a;
ERROR: aggregate functions are not allowed in GROUP BY
CONTEXT: Remote SQL command: EXPLAIN SELECT 2, avg(c1) FROM public.t1
GROUP BY 2
On Thu, Sep 8, 2016 at 10:41 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
While checking for shippability, we build the target list which is passed
to
the foreign server as fdw_scan_tlist. The target list contains
a. All the GROUP BY expressions
b. Shippable entries from the target list of upper relation
c. Var and Aggref nodes from non-shippable entries from the target list of
upper relationThe code in the patch doesn't seem to add Var nodes explicitly. It assumes
that
the Var nodes will be part of GROUP BY clause. The code is correct, I
think.d. Var and Aggref nodes from non-shippable HAVING conditions.
This needs to be changed as per the comments below.
Costing:
If use_foreign_estimate is true for input relation, like JOIN case, we use
EXPLAIN output to get the cost of query with aggregation/grouping on the
foreign server. If not we calculate the costs locally. Similar to core,
we use
get_agg_clause_costs() to get costs for aggregation and then using logic
similar to cost_agg() we calculate startup and total cost. Since we have
no
idea which aggregation strategy will be used at foreign side, we add all
startup cost (startup cost of input relation, aggregates etc.) into
startup
cost for the grouping path and similarly for total cost.This looks OK to me.
Deparsing the query:
Target list created while checking for shippability is deparsed using
deparseExplicitTargetList(). sortgroupref are adjusted according to this
target list. Most of the logic to deparse an Aggref is inspired from
get_agg_expr(). For an upper relation, FROM and WHERE clauses come from
the
underlying scan relation and thus for simplicity, FROM clause deparsing
logic
is moved from deparseSelectSql() to a new function deparseFromClause().
The
same function adds WHERE clause to the remote SQL.Ok.
Area of future work:
1. Adding path with path-keys to push ORDER BY clause along with
aggregation/
grouping. Should be supported as a separate patch.2. Grouping Sets/Rollup/Cube is not supported in current version. I have
left
this aside to keep patch smaller. If required I can add that support in
the
next version of the patch.I am fine with these limitations for first cut of this feature.
I think we should try to measure performance gain because of aggregate
pushdown. The EXPLAIN
doesn't show actual improvement in the execution times.Here are the comments on the patch.
Patch compiles without errors/warnings - Yes
make check passes - Yes.
make check in contrib/postgres_fdw passes - YesAttached patch (based on your patch) has some typos corrected, some
comments
rephrased. It also has some code changes, as explained in various comments
below. Please see if those look good.1. Usually for any deparseSomething function, Something is the type of node
produced by the parser when the string output by that function is parsed.
deparseColumnRef, for example, produces a string, which when parsed
produces a
columnRef node. There is are nodes of type FromClause and AggOrderBy. I
guess,
you meant FromExpr instead of FromClause. deparseAggOrderBy() may be
renamed as
appendOrderByFromList() or something similar. It may be utilized for window
functions if required.2. Can we infer the value of foragg flag from the RelOptInfo passed to
is_foreign_expr()? For any upper relation, it is ok to have aggregate in
there. For any other relation aggregate is not expected.3. In function foreign_grouping_ok(), should we use classifyConditions()?
The
function is written and used for base relations. There's nothing in that
function, which prohibits it being used for other relations. I feel that
foreign_join_ok() should have used the same function to classify the other
clauses.4. May be the individual criteria in the comment block + /* + * Aggregate is safe to pushdown if + * 1. It is a built-in aggregate + * 2. All its arguments are safe to push-down + * 3. The functions involved are immutable. + * 4. Other expressions involved like aggorder, aggdistinct are + * safe to be pushed down. + */ should be associated with the code blocks which implement those. As the criteria change it's difficult to maintain the numbered list in sync with the code.5. The comment
+ /* Aggregates other than simple one are non-pushable. */
should read /* Only non-split aggregates are pushable. */ as
AGGSPLIT_SIMPLE
means a complete, non-split aggregation step.6. An aggregate function has transition, combination and finalization
function
associated with it. Should we check whether all of the functions are
shippable?
But probably it suffices to check whether aggregate function as whole is
shippable or not using is_shippable() since it's the whole aggregate we are
interested in and not the intermediate results. Probably, we should add a
comment explaining why it's sufficient to check the aggregate function as a
whole. I wondered whether we should check shippability of aggregate return
type, but we don't do that for functions as well. So it's fine.7. It looks like aggdirectargs, aggdistinct, aggorder expressions are all
present in args list. If all the expressions in args are shippable, it
means
those lists are also shippable and hence corresponding aggregate
subclauses are
shippable. Are we unnecessarily checking shippability of those other lists?8. The prologue of build_tlist_to_deparse() mentions that the output
targetlist
contains columns, which is not true with your patch. The targetlist
returned by
this function can have expressions for upper relations. Please update the
prologue to reflect this change.9. In build_tlist_to_deparse(), we are including aggregates from
unshippable
conditions without checking whether they are shippable or not. This can
cause
an unshippable expression to be pushed to the foreign server as seen belowexplain verbose select avg(c1) from ft1 having avg(c1 * random()) > 100;
QUERY PLAN------------------------------------------------------------
--------------------------
Foreign Scan (cost=112.50..133.53 rows=1 width=32)
Output: (avg(c1))
Filter: ((avg(((ft1.c1)::double precision * random()))) > '100'::double
precision)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT avg(r1."C 1"), avg((r1."C 1" * random())) FROM "S
1"."T 1" r1
(5 rows)We should check shippability of aggregates in unshippable conditions in
foreign_grouping_ok(). If any of those are not shippable, aggregation can
not
be pushed down. Otherwise, include those in the grouped_tlist.10. Comment /* Construct FROM clause */ should read "Construct FROM and
WHERE
clauses." to be in sync with the next function call. deparseFromClause()
should
be renamed as deparseFromExpr() inline with the naming convention of
deparse<something> functions. From the function signature of
deparseFromClause(), it doesn't become clear as to what contributes to the
FROM
clause. Should we add a comment in the prologue of that function
explaining the
same. Also it strikes odd that for an upper relation, we pass remote_conds
to
this function, but it doesn't deparse those but deparses the remote
conditions
from the scan relation and later deparses the same remote_conds as HAVING
clause. Although this is correct, the code looks odd. May be the codeblock
in
deparseFuncClause()
1008 /*
1009 * For aggregates the FROM clause will be build from underneath
scan rel.
1010 * WHERE clause conditions too taken from there.
1011 */
1012 if (foreignrel->reloptkind == RELOPT_UPPER_REL)
1013 {
1014 PgFdwRelationInfo *ofpinfo;
1015
1016 ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
1017 scan_rel = fpinfo->outerrel;
1018 context->foreignrel = scan_rel;
1019 remote_conds = ofpinfo->remote_conds;
1020 }
should be moved into deparseSelectStmtForRel() to make the things clear.11. Whether to qualify a column name by an alias should be based on
whether the
underlying scan relation is a join or base relation scan. That can be
achieved
by setting scanrel in the deparse_context. Attached patch has this
implemented.
Instead of scanrel, we may also have use_alias value as part of the
context,
which is used everywhere.12. The code to print the function name in deparseAggref() seems similar to
that in deparseFuncExpr(). Should we extract it out into a separate
function
and call that function in deparseAggref() and deparseFuncExpr() both?13. While deparsing the direct aggregates, the code is not adding ","
between
two arguments, resulting in error like below.
select rank(c1, c2) within group (order by c1, c2) from ft1 group by c1,
c2;
ERROR: syntax error at or near "c2"
CONTEXT: Remote SQL command: SELECT rank("C 1"c2) WITHIN GROUP (ORDER BY
"C
1", c2), "C 1", c2 FROM "S 1"."T 1" GROUP BY "C 1", c2
May be we should add support to deparse List expressions by separating list
items by "," similar to get_rule_expr() and use that here.14. In deparseAggOrderBy() we do not output anything for default cases
like ASC
or NULLS FIRST (for DESC). But like appendOrderByClause() it's better to be
explicit and output even the default specifications. That way, we do not
leave
anything to the interpretation of the foreign server.15. deparseAggOrderBy supports deparsing USING subclause for ORDER BY for
an
aggregate, but there is no corresponding shippability check for ordering
operator. Also, we should try to produce a testcase for the same.16. The code to deparse a sort/group reference in deparseAggOrderBy() and
appendGroupByClause() looks similar. Should we extract it out into a
function
by itself and call that function in those two places similar to
get_rule_sortgroupclause()?17. In postgresGetForeignPlan() the code to extract conditions and
targetlist
is duplicated for join and upper relation. Attached patch removes this
duplication. Since DML, FOR SHARE/UPDATE is not allowed with aggregation
and
grouping, we should get an outer plan in that code.18. estimate_path_cost_size() has grown quite long (~400 lines). Half of
that
function deals with estimating costs locally. Should we split this function
into smaller functions, one for estimating size and costs of each kind of
relations locally?19. Condition below + if (sgref && query->groupClause && query->groupingSets == NIL && + get_sortgroupref_clause_noerr(sgref, query->groupClause) != NULL) can be rewritten as if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause)) since we won't come here with non-NULL query->groupingSets and get_sortgroupref_clause_noerr() will return NULL, if there aren't any groupClause.20. Please use word "foreign" instead of "remote" in comments.
21. This code looks dubious + /* If not GROUP BY ref, reset it as we are not pushing those */ + if (sgref) + grouping_target->sortgrouprefs[i] = 0; grouping_target comes from RelOptInfo, which is being modified here. We shouldn't be modifying anything in the RelOptInfo while checking whether the aggregate/grouping is shippable. You may want to copy the pathtaget and modify the copy.22. Following comment needs more elaboration. + /* + * Add aggregates, if any, into tlist. Plain Var nodes pulled + * are already part of GROUP BY and thus no need to add them + * explicitly. + */ Plain Var nodes will either be same as some GROUP BY expression or should be part of some GROUP BY expression. In the later case, the query can not refer those without the surrounding expression. which will be part of the targetlist list. Hence we don't need to add plain Var nodes in the targetlist. In fact adding those in SELECT clause will cause error on the foreign server if they are not part of GROUP BY clause.23. Probably you don't need to save this in fpinfo. You may want to
calculate
it whenever it's needed.
+ fpinfo->grouped_exprs = get_sortgrouplist_exprs(query->groupClause,
tlist);24. Can this ever happen for postgres_fdw? The core sets fdwroutine and calls this function when the underlying scan relation has fdwroutine set, which implies that it called corresponding GetForeignPath hooks, which should have set fdw_private. Nonetheless, I think, still the condition is useful to avoid crashing the server in case the fdw_private is not set. But we need better comments. + /* If input rel is not aware of fdw, simply return */ + if (!input_rel->fdw_private) + return;25. Although it's desirable to get a switch case in
postgresGetForeignUpperPaths() eventually, for this patch I guess we should
have an if condition there.26. Attached patch has restructured code in appendGroupByClause() to reduce
indentation and make the code readable. Let me know if this looks good to
you.27. Prologue of create_foreign_grouping_paths() does not have formatting
similar to the surrounding functions. Please fix it. Since the function
"create"s and "add"s paths, it might be better to rename it as
add_foreign_grouping_paths().28. Isn't the following true for any upper relation and shouldn't it be part of postgresGetForeignUpperPaths(), rather than create_foreign_grouping_paths( )? + /* + * If input rel is not safe to pushdown, we cannot do grouping and/or + * aggregation on it. + */ + if (!ifpinfo || !ifpinfo->pushdown_safe) + return;29. We require RelOptInfo::relids since create_foreignscan_plan() copies
them
into ForeignPlan::fs_relids and executor uses them. So, I guess, we have
to set
those in the core somewhere. May be while calling fetch_upper_rel() in
grouping_planner(), we should call it with relids of the underlying scan
relation. I don't see any function calling fetch_upper_rel() with non-NULL
relids. In fact, if we are to create an upper relation with relids in
future,
this code is going to wipe that out, which will be undesirable. Also,
generally, when copying relids, it's better to use bms_copy() to make a
copy
of Bitmapset, instead of just assigning the pointer.30. By the time postgresGetForeignUpperPaths() gets called, the core has
already added its own paths, so it doesn't make much sense to set rows and
width grouped_rel in create_foreign_grouping_paths().31. fpinfo->server and user fields are being set twice, once in
create_foreign_grouping_paths() then in foreign_grouping_ok(). Do we need
that?32. + /* + * Do we want to create paths with pathkeys corresponding for + * root->query_pathkeys. + */ Yes, it would be desirable to do that. If we are not going to do that in this patch, may be remove that line or add a TODO kind of comment.33. The patch marks build_path_tlist() as non-static but does not use it
anywhere outside creatplan.c. Is this change intentional?--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
--
*Thanks & Regards,*
*Prabhat Kumar Sahu*
Mob: 7758988455
Skype ID: prabhat.sahu1984
www.enterprisedb.co <http://www.enterprisedb.com/>m
<http://www.enterprisedb.com/>
On Thu, Sep 8, 2016 at 10:41 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
While checking for shippability, we build the target list which is passed
to
the foreign server as fdw_scan_tlist. The target list contains
a. All the GROUP BY expressions
b. Shippable entries from the target list of upper relation
c. Var and Aggref nodes from non-shippable entries from the target list of
upper relationThe code in the patch doesn't seem to add Var nodes explicitly. It assumes
that
the Var nodes will be part of GROUP BY clause. The code is correct, I
think.
Yes. Code is correct. Var nodes are already part of GROUP BY else we hit
error well before this point.
Thanks Ashutosh for the detailed review comments.
I am working on it and will post updated patch once I fix all your concerns.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Mon, Sep 12, 2016 at 12:20 PM, Prabhat Sahu <
prabhat.sahu@enterprisedb.com> wrote:
Hi,
While testing "Aggregate pushdown", i found the below error:
-- GROUP BY alias showing different behavior after adding patch.-- Create table "t1", insert few records.
create table t1(c1 int);
insert into t1 values(10), (20);-- Create foreign table:
create foreign table f_t1 (c1 int) server db1_server options (table_name
't1');-- with local table:
postgres=# select 2 a, avg(c1) from t1 group by a;
a | avg
---+---------------------
2 | 15.0000000000000000
(1 row)-- with foreign table:
postgres=# select 2 a, avg(c1) from f_t1 group by a;
ERROR: aggregate functions are not allowed in GROUP BY
CONTEXT: Remote SQL command: EXPLAIN SELECT 2, avg(c1) FROM public.t1
GROUP BY 2
Thanks for reporting this bug in *v1.patch Prabhat.
I will have a look over this issue and will post a fix in next version.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Hi,
On Mon, Sep 12, 2016 at 5:17 PM, Jeevan Chalke <
jeevan.chalke@enterprisedb.com> wrote:
Thanks Ashutosh for the detailed review comments.
I am working on it and will post updated patch once I fix all your
concerns.
Attached new patch fixing the review comments.
Here are few comments on the review points:
1. Renamed deparseFromClause() to deparseFromExpr() and
deparseAggOrderBy() to appendAggOrderBy()
2. Done
3. classifyConditions() assumes list expressions of type RestrictInfo. But
HAVING clause expressions (and JOIN conditions) are plain expressions. Do
you mean we should modify the classifyConditions()? If yes, then I think it
should be done as a separate (cleanup) patch.
4, 5. Both done.
6. Per my understanding, I think checking for just aggregate function is
enough as we are interested in whole aggregate result. Meanwhile I will
check whether we need to find and check shippability of transition,
combination and finalization functions or not.
7, 8, 9, 10, 11, 12. All done.
13. Fixed. However instead of adding new function made those changes inline.
Adding support for deparsing List expressions separating list by comma can
be
considered as cleanup patch as it will touch other code area not specific to
aggregate push down.
14, 15, 16, 17. All done.
18. I think re-factoring estimate_path_cost_size() should be done separately
as a cleanup patch too.
19, 20, 21, 22, 23, 24, 25, 26, 27, 28. All done.
29. I have tried passing input rel's relids to fetch_upper_rel() call in
create_grouping_paths(). It solved this patch's issue, but ended up with
few regression failures which is mostly plan changes. I am not sure whether
we get good plan now or not as I have not analyzed them.
So for this patch, I am setting relids in add_foreign_grouping_path()
itself.
However as suggested, used bms_copy(). I still kept the FIXME over there as
I think it should have done by the core itself.
30, 31, 32, 33. All done.
Let me know your views.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Attachments:
pg_agg_push_down_v2.patchtext/x-patch; charset=US-ASCII; name=pg_agg_push_down_v2.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..b4e5893 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -38,6 +38,7 @@
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/sysattr.h"
+#include "catalog/pg_aggregate.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_namespace.h"
#include "catalog/pg_operator.h"
@@ -47,6 +48,7 @@
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/plannodes.h"
+#include "nodes/print.h"
#include "optimizer/clauses.h"
#include "optimizer/prep.h"
#include "optimizer/tlist.h"
@@ -55,7 +57,9 @@
#include "utils/builtins.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
+#include "utils/ruleutils.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
/*
@@ -93,7 +97,9 @@ typedef struct foreign_loc_cxt
typedef struct deparse_expr_cxt
{
PlannerInfo *root; /* global planner state */
+
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ RelOptInfo *scanrel; /* the underlying scan relation. */
StringInfo buf; /* output buffer to append to */
List **params_list; /* exprs that will become remote Params */
} deparse_expr_cxt;
@@ -135,7 +141,7 @@ static void deparseColumnRef(StringInfo buf, int varno, int varattno,
static void deparseRelation(StringInfo buf, Relation rel);
static void deparseExpr(Expr *expr, deparse_expr_cxt *context);
static void deparseVar(Var *node, deparse_expr_cxt *context);
-static void deparseConst(Const *node, deparse_expr_cxt *context);
+static void deparseConst(Const *node, deparse_expr_cxt *context, int showtype);
static void deparseParam(Param *node, deparse_expr_cxt *context);
static void deparseArrayRef(ArrayRef *node, deparse_expr_cxt *context);
static void deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context);
@@ -159,6 +165,14 @@ static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context);
static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *joinrel, bool use_alias, List **params_list);
+static void deparseFromExpr(List *quals, deparse_expr_cxt *context);
+static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
+static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
+static void appendAggOrderBy(List *orderList, List *targetList,
+ deparse_expr_cxt *context);
+static void appendFunctionName(Oid funcid, deparse_expr_cxt *context);
+static Node *appendSortGroupClause(Index ref, List *tlist,
+ deparse_expr_cxt *context);
/*
@@ -631,6 +645,111 @@ foreign_expr_walker(Node *node,
check_type = false;
}
break;
+ case T_Aggref:
+ {
+ Aggref *agg = (Aggref *) node;
+ ListCell *lc;
+
+ /* Not safe to pushdown when not in grouping context */
+ if (glob_cxt->foreignrel->reloptkind != RELOPT_UPPER_REL)
+ return false;
+
+ /* Only non-split aggregates are pushable. */
+ if (agg->aggsplit != AGGSPLIT_SIMPLE)
+ return false;
+
+ /*
+ * If aggregate function used by the expression is not
+ * shippable, it can't be sent to remote because it might
+ * have incompatible semantics on remote side.
+ */
+ if (!is_shippable(agg->aggfnoid, ProcedureRelationId, fpinfo))
+ return false;
+
+ /*
+ * Recurse to input args. aggdirectargs and aggdistinct are
+ * all present in args, so no need to check their shippability
+ * explicitly.
+ */
+ foreach(lc, agg->args)
+ {
+ Node *n = (Node *) lfirst(lc);
+
+ /* If TargetEntry, extract the expression from it */
+ if (IsA(n, TargetEntry))
+ {
+ TargetEntry *tle = (TargetEntry *) n;
+ n = (Node *) tle->expr;
+ }
+
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+
+ /*
+ * aggorder too present into args so no need to check its
+ * shippability explicitly. However, if any expression has
+ * USING clause with sort operator, we need to make sure the
+ * shippability of that operator.
+ */
+ if (agg->aggorder)
+ {
+ ListCell *lc;
+
+ foreach (lc, agg->aggorder)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+ TargetEntry *tle;
+
+ tle = get_sortgroupref_tle(srt->tleSortGroupRef,
+ agg->args);
+ sortcoltype = exprType((Node *) tle->expr);
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ /* Check shippability of non-default sort operator. */
+ if (srt->sortop != typentry->lt_opr &&
+ srt->sortop != typentry->gt_opr)
+ if (!is_shippable(srt->sortop, OperatorRelationId,
+ fpinfo))
+ return false;
+ }
+ }
+
+ /* Check aggregate filter */
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
+ if (agg->inputcollid == InvalidOid)
+ /* OK, inputs are all noncollatable */ ;
+ else if (inner_cxt.state != FDW_COLLATE_SAFE ||
+ agg->inputcollid != inner_cxt.collation)
+ return false;
+
+ /*
+ * Detect whether node is introducing a collation not derived
+ * from a foreign Var. (If so, we just mark it unsafe for now
+ * rather than immediately returning false, since the parent
+ * node might not care.)
+ */
+ collation = agg->aggcollid;
+ if (collation == InvalidOid)
+ state = FDW_COLLATE_NONE;
+ else if (inner_cxt.state == FDW_COLLATE_SAFE &&
+ collation == inner_cxt.collation)
+ state = FDW_COLLATE_SAFE;
+ else if (collation == DEFAULT_COLLATION_OID)
+ state = FDW_COLLATE_NONE;
+ else
+ state = FDW_COLLATE_UNSAFE;
+ }
+ break;
default:
/*
@@ -720,7 +839,9 @@ deparse_type_name(Oid type_oid, int32 typemod)
* Build the targetlist for given relation to be deparsed as SELECT clause.
*
* The output targetlist contains the columns that need to be fetched from the
- * foreign server for the given relation.
+ * foreign server for the given relation. If foreignrel is an upper relation,
+ * then the output targetlist can also contains expressions to be evaluated on
+ * foreign server.
*/
List *
build_tlist_to_deparse(RelOptInfo *foreignrel)
@@ -729,6 +850,13 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
/*
+ * For upper relation, we have already built the target list while checking
+ * shippability, return that.
+ */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ return fpinfo->grouped_tlist;
+
+ /*
* We require columns specified in foreignrel->reltarget->exprs and those
* required for evaluating the local conditions.
*/
@@ -750,6 +878,7 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
* hence the tlist is ignored for a base relation.
*
* remote_conds is the list of conditions to be deparsed as WHERE clause.
+ * However for upper relation it is deparsed as HAVING clause.
*
* If params_list is not NULL, it receives a list of Params and other-relation
* Vars used in the clauses; these values must be transmitted to the remote
@@ -768,28 +897,50 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *)rel->fdw_private;
+ List *quals;
- /* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
- rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* We handle all relations other than dead one. */
+ Assert(rel->reloptkind != RELOPT_DEADREL);
- /* Fill portions of context common to join and base relation */
+ /* Fill portions of context common to upper, join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ? fpinfo->outerrel : rel;
context.params_list = params_list;
- /* Construct SELECT clause and FROM clause */
+ /* Construct SELECT clause */
deparseSelectSql(tlist, retrieved_attrs, &context);
/*
- * Construct WHERE clause
+ * For upper relations, WHERE clause is built from the underneath scan
+ * relation's remote conditions.
*/
- if (remote_conds)
+ if (rel->reloptkind == RELOPT_UPPER_REL)
{
- appendStringInfo(buf, " WHERE ");
- appendConditions(remote_conds, &context);
+ PgFdwRelationInfo *ofpinfo;
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+ quals = ofpinfo->remote_conds;
+ }
+ else
+ quals = remote_conds;
+
+ /* Construct FROM and WHERE clauses */
+ deparseFromExpr(quals, &context);
+
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ {
+ /* Append GROUP BY clause */
+ appendGroupByClause(tlist, &context);
+
+ /* Append HAVING clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " HAVING ");
+ appendConditions(remote_conds, &context);
+ }
}
/* Add ORDER BY clause if we found any useful pathkeys */
@@ -803,7 +954,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
/*
* Construct a simple SELECT statement that retrieves desired columns
* of the specified foreign table, and append it to "buf". The output
- * contains just "SELECT ... FROM ....".
+ * contains just "SELECT ... ".
*
* We also create an integer List of the columns being retrieved, which is
* returned to *retrieved_attrs.
@@ -824,7 +975,8 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -847,14 +999,33 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
+}
- /*
- * Construct FROM clause
- */
+/*
+ * Construct a FROM clause and a WHERE clause, if any, and append those to
+ * "buf".
+ *
+ * quals is the list of clauses to be included in the WHERE clause,
+ * NIL if none.
+ */
+static void
+deparseFromExpr(List *quals, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ RelOptInfo *scan_rel = context->scanrel;
+
+ /* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, context->root, scan_rel,
+ (scan_rel->reloptkind == RELOPT_JOINREL),
context->params_list);
+
+ /* Construct WHERE clause */
+ if (quals)
+ {
+ appendStringInfo(buf, " WHERE ");
+ appendConditions(quals, context);
+ }
}
/*
@@ -957,14 +1128,14 @@ deparseTargetList(StringInfo buf,
/*
* Deparse the appropriate locking clause (FOR UPDATE or FOR SHARE) for a
- * given relation (context->foreignrel).
+ * given relation (context->scanrel).
*/
static void
deparseLockingClause(deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
PlannerInfo *root = context->root;
- RelOptInfo *rel = context->foreignrel;
+ RelOptInfo *rel = context->scanrel;
int relid = -1;
while ((relid = bms_next_member(rel->relids, relid)) >= 0)
@@ -1036,7 +1207,7 @@ deparseLockingClause(deparse_expr_cxt *context)
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
- * deparse both WHERE clauses and JOIN .. ON clauses.
+ * deparse WHERE clauses, JOIN .. ON clauses and HAVING clauses.
*/
static void
appendConditions(List *exprs, deparse_expr_cxt *context)
@@ -1126,22 +1297,15 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
foreach(lc, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
- Var *var;
/* Extract expression if TargetEntry node */
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
-
- /* We expect only Var nodes here */
- if (!IsA(var, Var))
- elog(ERROR, "non-Var not expected in target list");
if (i > 0)
appendStringInfoString(buf, ", ");
- deparseVar(var, context);
+ deparseExpr((Expr *) tle->expr, context);
*retrieved_attrs = lappend_int(*retrieved_attrs, i + 1);
-
i++;
}
@@ -1192,6 +1356,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
context.buf = buf;
context.foreignrel = foreignrel;
+ context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
@@ -1360,6 +1525,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1444,6 +1610,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1817,7 +1984,7 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
deparseVar((Var *) node, context);
break;
case T_Const:
- deparseConst((Const *) node, context);
+ deparseConst((Const *) node, context, 0);
break;
case T_Param:
deparseParam((Param *) node, context);
@@ -1849,6 +2016,9 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
case T_ArrayExpr:
deparseArrayExpr((ArrayExpr *) node, context);
break;
+ case T_Aggref:
+ deparseAggref((Aggref *)node, context);
+ break;
default:
elog(ERROR, "unsupported expression type for deparse: %d",
(int) nodeTag(node));
@@ -1867,9 +2037,10 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ bool qualify_col = (context->scanrel->reloptkind == RELOPT_JOINREL ||
+ context->scanrel->reloptkind == RELOPT_UPPER_REL);
- if (bms_is_member(node->varno, context->foreignrel->relids) &&
+ if (bms_is_member(node->varno, context->scanrel->relids) &&
node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
@@ -1910,7 +2081,7 @@ deparseVar(Var *node, deparse_expr_cxt *context)
* This function has to be kept in sync with ruleutils.c's get_const_expr.
*/
static void
-deparseConst(Const *node, deparse_expr_cxt *context)
+deparseConst(Const *node, deparse_expr_cxt *context, int showtype)
{
StringInfo buf = context->buf;
Oid typoutput;
@@ -1922,9 +2093,10 @@ deparseConst(Const *node, deparse_expr_cxt *context)
if (node->constisnull)
{
appendStringInfoString(buf, "NULL");
- appendStringInfo(buf, "::%s",
- deparse_type_name(node->consttype,
- node->consttypmod));
+ if (showtype >= 0)
+ appendStringInfo(buf, "::%s",
+ deparse_type_name(node->consttype,
+ node->consttypmod));
return;
}
@@ -1974,9 +2146,14 @@ deparseConst(Const *node, deparse_expr_cxt *context)
break;
}
+ pfree(extval);
+
+ if (showtype < 0)
+ return;
+
/*
- * Append ::typename unless the constant will be implicitly typed as the
- * right type when it is read in.
+ * For showtype == 0, append ::typename unless the constant will be
+ * implicitly typed as the right type when it is read in.
*
* XXX this code has to be kept in sync with the behavior of the parser,
* especially make_const.
@@ -1995,7 +2172,7 @@ deparseConst(Const *node, deparse_expr_cxt *context)
needlabel = true;
break;
}
- if (needlabel)
+ if (needlabel || showtype > 0)
appendStringInfo(buf, "::%s",
deparse_type_name(node->consttype,
node->consttypmod));
@@ -2092,9 +2269,6 @@ static void
deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
- HeapTuple proctup;
- Form_pg_proc procform;
- const char *proname;
bool use_variadic;
bool first;
ListCell *arg;
@@ -2127,29 +2301,15 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
return;
}
- /*
- * Normal function: display as proname(args).
- */
- proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->funcid));
- if (!HeapTupleIsValid(proctup))
- elog(ERROR, "cache lookup failed for function %u", node->funcid);
- procform = (Form_pg_proc) GETSTRUCT(proctup);
-
/* Check if need to print VARIADIC (cf. ruleutils.c) */
use_variadic = node->funcvariadic;
- /* Print schema name only if it's not pg_catalog */
- if (procform->pronamespace != PG_CATALOG_NAMESPACE)
- {
- const char *schemaname;
-
- schemaname = get_namespace_name(procform->pronamespace);
- appendStringInfo(buf, "%s.", quote_identifier(schemaname));
- }
+ /*
+ * Normal function: display as proname(args).
+ */
+ appendFunctionName(node->funcid, context);
+ appendStringInfoChar(buf, '(');
- /* Deparse the function name ... */
- proname = NameStr(procform->proname);
- appendStringInfo(buf, "%s(", quote_identifier(proname));
/* ... and all the arguments */
first = true;
foreach(arg, node->args)
@@ -2162,8 +2322,6 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
first = false;
}
appendStringInfoChar(buf, ')');
-
- ReleaseSysCache(proctup);
}
/*
@@ -2420,6 +2578,151 @@ deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context)
}
/*
+ * Deparse an Aggref node.
+ */
+static void
+deparseAggref(Aggref *node, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ bool use_variadic;
+
+ /* Only basic, non-split aggregation accepted. */
+ Assert(node->aggsplit == AGGSPLIT_SIMPLE);
+
+ /* Check if need to print VARIADIC (cf. ruleutils.c) */
+ use_variadic = node->aggvariadic;
+
+ /* Find aggregate name from aggfnoid which is a pg_proc entry */
+ appendFunctionName(node->aggfnoid, context);
+ appendStringInfoChar(buf, '(');
+
+ /* Add DISTINCT */
+ appendStringInfo(buf, "%s", (node->aggdistinct != NIL) ? "DISTINCT " : "");
+
+ if (AGGKIND_IS_ORDERED_SET(node->aggkind))
+ {
+ /* Add WITHIN GROUP (ORDER BY ..) */
+ ListCell *arg;
+ bool first = true;
+
+ Assert(!node->aggvariadic);
+ Assert(node->aggorder != NIL);
+
+ foreach(arg, node->aggdirectargs)
+ {
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseExpr((Expr *) lfirst(arg), context);
+ }
+
+ appendStringInfoString(buf, ") WITHIN GROUP (ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ else
+ {
+ /* aggstar can be set only in zero-argument aggregates */
+ if (node->aggstar)
+ appendStringInfoChar(buf, '*');
+ else
+ {
+ ListCell *arg;
+ bool first = true;
+
+ /* ... and all the arguments */
+ foreach(arg, node->args)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(arg);
+ Node *n = (Node *) tle->expr;
+
+ if (tle->resjunk)
+ continue;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ /* Add VARIADIC */
+ if (use_variadic && lnext(arg) == NULL)
+ appendStringInfoString(buf, "VARIADIC ");
+
+ deparseExpr((Expr *) n, context);
+ }
+ }
+
+ /* Add ORDER BY */
+ if (node->aggorder != NIL)
+ {
+ appendStringInfoString(buf, " ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ }
+
+ /* Add FILTER (WHERE ..) */
+ if (node->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ deparseExpr((Expr *) node->aggfilter, context);
+ }
+
+ appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Append ORDER BY within aggregate function.
+ */
+static void
+appendAggOrderBy(List *orderList, List *targetList, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ ListCell *lc;
+ bool first = true;
+
+ foreach (lc, orderList)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Node *sortexpr;
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ sortexpr = appendSortGroupClause(srt->tleSortGroupRef, targetList, context);
+ sortcoltype = exprType(sortexpr);
+ /* See whether operator is default < or > for datatype */
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ if (srt->sortop == typentry->lt_opr)
+ appendStringInfoString(buf, " ASC");
+ else if (srt->sortop == typentry->gt_opr)
+ appendStringInfoString(buf, " DESC");
+ else
+ {
+ HeapTuple opertup;
+ Form_pg_operator operform;
+
+ appendStringInfoString(buf, " USING ");
+
+ /* Append operator name. */
+ opertup = SearchSysCache1(OPEROID, ObjectIdGetDatum(srt->sortop));
+ if (!HeapTupleIsValid(opertup))
+ elog(ERROR, "cache lookup failed for operator %u", srt->sortop);
+ operform = (Form_pg_operator) GETSTRUCT(opertup);
+ deparseOperatorName(buf, operform);
+ ReleaseSysCache(opertup);
+ }
+
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ else
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+}
+
+/*
* Print the representation of a parameter to be sent to the remote side.
*
* Note: we always label the Param's type explicitly rather than relying on
@@ -2464,6 +2767,41 @@ printRemotePlaceholder(Oid paramtype, int32 paramtypmod,
}
/*
+ * Deparse GROUP BY clause.
+ */
+static void
+appendGroupByClause(List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ Query *query = context->root->parse;
+ ListCell *lc;
+ bool first = true;
+
+ /* Nothing to be done, if there's no GROUP BY clause in the query. */
+ if (!query->groupClause)
+ return;
+
+ appendStringInfo(buf, " GROUP BY ");
+
+ /*
+ * Queries with grouping sets are not pushed down, so we don't grouping
+ * sets here.
+ */
+ Assert(!query->groupingSets);
+
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ appendSortGroupClause(grp->tleSortGroupRef, tlist, context);
+ }
+}
+
+/*
* Deparse ORDER BY clause according to the given pathkeys for given base
* relation. From given pathkeys expressions belonging entirely to the given
* base relation are obtained and deparsed.
@@ -2474,7 +2812,7 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
ListCell *lcell;
int nestlevel;
char *delim = " ";
- RelOptInfo *baserel = context->foreignrel;
+ RelOptInfo *baserel = context->scanrel;
StringInfo buf = context->buf;
/* Make sure any constants in the exprs are printed portably */
@@ -2505,3 +2843,67 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
}
reset_transmission_modes(nestlevel);
}
+
+/*
+ * appendFunctionName
+ * Deparses function name from given function oid.
+ */
+static void
+appendFunctionName(Oid funcid, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ HeapTuple proctup;
+ Form_pg_proc procform;
+ const char *proname;
+
+ proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
+ if (!HeapTupleIsValid(proctup))
+ elog(ERROR, "cache lookup failed for function %u", funcid);
+ procform = (Form_pg_proc) GETSTRUCT(proctup);
+
+ /* Print schema name only if it's not pg_catalog */
+ if (procform->pronamespace != PG_CATALOG_NAMESPACE)
+ {
+ const char *schemaname;
+
+ schemaname = get_namespace_name(procform->pronamespace);
+ appendStringInfo(buf, "%s.", quote_identifier(schemaname));
+ }
+
+ /* Deparse the function name ... */
+ proname = NameStr(procform->proname);
+ appendStringInfo(buf, "%s", quote_identifier(proname));
+
+ ReleaseSysCache(proctup);
+}
+
+/*
+ * Appends a sort or group clause.
+ *
+ * Like get_rule_sortgroupclause(), returns the expression tree, so caller
+ * need not find it again.
+ */
+static Node *
+appendSortGroupClause(Index ref, List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ TargetEntry *tle;
+ Expr *expr;
+
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context, 1);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Must force parens for other expressions */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+
+ return (Node *) expr;
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d97e694..84713b9 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,14 +861,13 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
---------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
-(5 rows)
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
count
@@ -878,14 +877,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
----------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = c2))
-(5 rows)
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
count
@@ -937,14 +935,13 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
-----------------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
count
@@ -954,14 +951,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
count
@@ -4441,12 +4437,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
--------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4485,12 +4481,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
---------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
@@ -5881,3 +5877,2086 @@ AND ftoptions @> array['fetch_size=60000'];
(1 row)
ROLLBACK;
+-- Test Aggregate Push Down
+-- Both ft1 and ft2 are used to exercise cost estimates when
+-- use_remote_estimate is false and true respectively.
+-- A. Simple aggregates
+explain (verbose, costs off)
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) FROM "S 1"."T 1"
+(4 rows)
+
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+ sum | avg | min | max | stddev
+--------+----------------------+-----+------+------------------
+ 423821 | 515.5973236009732360 | 1 | 1218 | 233.490919491320
+(1 row)
+
+select sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) from "S 1"."T 1";
+ sum | avg | min | max | stddev
+--------+----------------------+-----+------+------------------
+ 423821 | 515.5973236009732360 | 1 | 1218 | 233.490919491320
+(1 row)
+
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+ QUERY PLAN
+------------------------------------------------------
+ Foreign Scan
+ Output: (((sum(c1)))::double precision * random())
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+(4 rows)
+
+explain (verbose, costs off)
+select count(c6) from ft1;
+ QUERY PLAN
+-------------------------------------------------
+ Foreign Scan
+ Output: (count(c6))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6) FROM "S 1"."T 1"
+(4 rows)
+
+select count(c6) from ft1;
+ count
+-------
+ 801
+(1 row)
+
+select count(c6) from "S 1"."T 1";
+ count
+-------
+ 801
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------
+ Aggregate
+ Output: sum(((c1)::double precision * random())), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1" WHERE ((c2 < 5))
+(4 rows)
+
+select sum(c1) from ft2 where c2 < 5;
+ sum
+-------
+ 50711
+(1 row)
+
+select sum("C 1") from "S 1"."T 1" where c2 < 5;
+ sum
+-------
+ 50711
+(1 row)
+
+explain (verbose, costs off)
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ sum | avg
+---------+----------------------
+ 5010000 | 501.0000000000000000
+(1 row)
+
+select sum(t1."C 1"), avg(t1."C 1") from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ sum | avg
+---------+----------------------
+ 5010000 | 501.0000000000000000
+(1 row)
+
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT count(*) FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ count
+-------
+ 10000
+(1 row)
+
+select count(*) from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+ count
+-------
+ 10000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Nested Loop
+ Join Filter: ((t1.c2)::double precision = ((t2.c2)::double precision * random()))
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft1 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(12 rows)
+
+-- B. Aggregates with GROUP BY
+explain (verbose, costs off)
+select c2, count(*) from ft1 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Sort
+ Output: c2, (count(*))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, count(*) FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select c2, count(*) from ft1 group by c2 order by 1;
+ c2 | count
+-----+-------
+ 1 | 99
+ 2 | 2
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+ 503 | 1
+ 507 | 2
+ 509 | 100
+ 608 | 100
+ 609 | 2
+ 708 | 2
+ 818 | 2
+(21 rows)
+
+select c2, count(*) from "S 1"."T 1" group by c2 order by 1;
+ c2 | count
+-----+-------
+ 1 | 99
+ 2 | 2
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+ 503 | 1
+ 507 | 2
+ 509 | 100
+ 608 | 100
+ 609 | 2
+ 708 | 2
+ 818 | 2
+(21 rows)
+
+explain (verbose, costs off)
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c1)), (length((c6)::text)), c6
+ Sort Key: (count(ft2.c1)), (length((ft2.c6)::text))
+ -> Foreign Scan
+ Output: (count(c1)), (length((c6)::text)), c6
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT count("C 1"), length(c6), c6 FROM "S 1"."T 1" GROUP BY c6
+(7 rows)
+
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+ count | length
+-------+--------
+ 1 | 4
+ 21 |
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+(10 rows)
+
+select count("C 1"), length(c6) from "S 1"."T 1" group by c6 order by 1, 2;
+ count | length
+-------+--------
+ 1 | 4
+ 21 |
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+ 100 | 1
+(10 rows)
+
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Sort Key: ((ft1.c2 / 2))
+ -> Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
+(7 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 4
+ 3 | 1800
+ 21 | 88200
+ 22 | 96800
+ 50 | 20100
+ 52 | 10816
+ 53 | 11236
+ 100 | 20100
+ 102 | 20808
+ 151 | 4575300
+ 201 | 162006
+ 203 | 8262100
+ 251 | 126253
+ 253 | 256542
+ 254 | 12928600
+ 304 | 18853472
+ 354 | 501264
+ 409 | 669124
+(19 rows)
+
+select c2/2, sum(c2) * (c2/2) from "S 1"."T 1" group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 4
+ 3 | 1800
+ 21 | 88200
+ 22 | 96800
+ 50 | 20100
+ 52 | 10816
+ 53 | 11236
+ 100 | 20100
+ 102 | 20808
+ 151 | 4575300
+ 201 | 162006
+ 203 | 8262100
+ 251 | 126253
+ 253 | 256542
+ 254 | 12928600
+ 304 | 18853472
+ 354 | 501264
+ 409 | 669124
+(19 rows)
+
+explain (verbose, costs off)
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Sort
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Sort Key: ft1.c2, (sum(ft1.c1))
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
+(9 rows)
+
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+--------
+ 822 | 199823
+(1 row)
+
+select count(a), sum(a) from (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2, sqrt("C 1") order by 1, 2) x;
+ count | sum
+-------+--------
+ 822 | 199823
+(1 row)
+
+-- Aggregate is still pushed down by taking random() out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c1)::double precision * random()), ((sum(c1) * c1)), c1
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * "C 1"), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(4 rows)
+
+--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select "C 1" * random(), sum("C 1") * "C 1" from "S 1"."T 1" group by "C 1";
+-- Aggregate is not pushed down as random() is part of group by expression
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+ QUERY PLAN
+--------------------------------------------------------------
+ HashAggregate
+ Output: (((c1)::double precision * random())), c2
+ Group Key: ((ft2.c1)::double precision * random()), ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: ((c1)::double precision * random()), c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+explain (verbose, costs off)
+select count(c2), 5 from ft1 group by 2;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5 FROM "S 1"."T 1" GROUP BY 5::integer
+(4 rows)
+
+select count(c2), 5 from ft1 group by 2;
+ count | ?column?
+-------+----------
+ 822 | 5
+(1 row)
+
+select count(c2), 5 from "S 1"."T 1" group by 2;
+ count | ?column?
+-------+----------
+ 822 | 5
+(1 row)
+
+explain (verbose, costs off)
+select count(c2) a, 5.0 b from ft1 group by b;
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5.0)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5.0 FROM "S 1"."T 1" GROUP BY 5.0::numeric
+(4 rows)
+
+select count(c2) a, 5.0 b from ft1 group by b;
+ a | b
+-----+-----
+ 822 | 5.0
+(1 row)
+
+select count(c2) a, 5.0 b from "S 1"."T 1" group by b;
+ a | b
+-----+-----
+ 822 | 5.0
+(1 row)
+
+explain (verbose, costs off)
+select count(c2) from ft1 group by 5::int;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5 FROM "S 1"."T 1" GROUP BY 5::integer
+(4 rows)
+
+select count(c2) from ft1 group by 5::int;
+ count
+-------
+ 822
+(1 row)
+
+select count(c2) from "S 1"."T 1" group by 5::int;
+ count
+-------
+ 822
+(1 row)
+
+-- C. Aggregates with HAVING clause
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 order by 1;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 200000))
+(7 rows)
+
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 and sum("C 1") < 200000 order by c2;
+ c2 | sum
+-----+-------
+ 44 | 49900
+ 303 | 49800
+(2 rows)
+
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Sort Key: ft1.c5, (count(ft1.c2))
+ -> Foreign Scan
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) < 2::double precision))
+(7 rows)
+
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Fri Jan 02 00:00:00 1970 | 1
+ Fri Jan 02 00:00:00 1970 | 9
+ Mon Jan 12 00:00:00 1970 | 10
+ Thu Jan 22 00:00:00 1970 | 10
+ Sun Feb 01 00:00:00 1970 | 10
+ Wed Feb 11 00:00:00 1970 | 10
+ Sat Feb 21 00:00:00 1970 | 10
+ Tue Mar 03 00:00:00 1970 | 10
+ Fri Mar 13 00:00:00 1970 | 10
+ Mon Mar 23 00:00:00 1970 | 10
+ Thu Apr 02 00:00:00 1970 | 10
+ | 1
+(12 rows)
+
+select c5, count(c2) from "S 1"."T 1" group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Fri Jan 02 00:00:00 1970 | 1
+ Fri Jan 02 00:00:00 1970 | 9
+ Mon Jan 12 00:00:00 1970 | 10
+ Thu Jan 22 00:00:00 1970 | 10
+ Sun Feb 01 00:00:00 1970 | 10
+ Wed Feb 11 00:00:00 1970 | 10
+ Sat Feb 21 00:00:00 1970 | 10
+ Tue Mar 03 00:00:00 1970 | 10
+ Fri Mar 13 00:00:00 1970 | 10
+ Mon Mar 23 00:00:00 1970 | 10
+ Thu Apr 02 00:00:00 1970 | 10
+ | 1
+(12 rows)
+
+-- Having clause with random() will be evaluated locally
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Filter: ((((sum(ft2.c1)))::double precision * random()) < '500000'::double precision)
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
+(8 rows)
+
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+ c2 | sum
+-----+-------
+ 1 | 49599
+ 2 | 1112
+ 6 | 50100
+ 42 | 50500
+ 44 | 49900
+ 100 | 2030
+ 101 | 2012
+ 104 | 2018
+ 106 | 2022
+ 201 | 1101
+ 204 | 1104
+ 303 | 49800
+ 403 | 2016
+ 407 | 50200
+ 503 | 1103
+ 507 | 2024
+ 509 | 50400
+ 608 | 50300
+ 609 | 2028
+ 708 | 2026
+ 818 | 2426
+(21 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 500000 order by c2;
+ c2 | sum
+-----+-------
+ 1 | 49599
+ 2 | 1112
+ 6 | 50100
+ 42 | 50500
+ 44 | 49900
+ 100 | 2030
+ 101 | 2012
+ 104 | 2018
+ 106 | 2022
+ 201 | 1101
+ 204 | 1104
+ 303 | 49800
+ 403 | 2016
+ 407 | 50200
+ 503 | 1103
+ 507 | 2024
+ 509 | 50400
+ 608 | 50300
+ 609 | 2028
+ 708 | 2026
+ 818 | 2426
+(21 rows)
+
+-- Having clause with random() will be evaluated locally, and other having qual is pushed
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
+ Filter: ((((avg(ft1.c1)))::double precision * random()) < '500'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ count
+-------
+ 39
+(1 row)
+
+select count(*) from (select c5, count("C 1") from "S 1"."T 1" group by c5, sqrt(c2) having avg("C 1") * random() < 500 and avg("C 1") < 500) x;
+ count
+-------
+ 39
+(1 row)
+
+-- Aggregate in having clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * random()) > 100;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg(((ft1.c1)::double precision * random())) > '100'::double precision)
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(7 rows)
+
+-- D. ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+explain (verbose, costs off)
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c3))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY c3 ASC NULLS LAST) FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+select array_agg("C 1" order by c3) from "S 1"."T 1" where c2 = 6 and "C 1" < 100;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Sort Key: (array_agg(ft2.c1 ORDER BY ft2.c1))
+ -> Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
+(7 rows)
+
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+ {11,21,31,41,51,61,71,81,91}
+(9 rows)
+
+select array_agg("C 1" order by "C 1") from "S 1"."T 1" where "C 1" < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+ {11,21,31,41,51,61,71,81,91}
+(9 rows)
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 DESC)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" DESC NULLS FIRST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {96,86,76,66,56,46,36,26,16,6}
+(1 row)
+
+select array_agg("C 1" order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+ array_agg
+--------------------------------
+ {96,86,76,66,56,46,36,26,16,6}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+select array_agg(c5 order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS FIRST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {4,3,2,1,0}
+ {NULL,3,2,1}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {4,3,2,1,0}
+ {NULL,3,2,1}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3)) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+select sum("C 1"%3), sum(distinct "C 1"%3) filter (where "C 1"%3 < 2), c2 from "S 1"."T 1" where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Unique
+ Output: (sum(c1)), c2
+ -> Sort
+ Output: (sum(c1)), c2
+ Sort Key: ft2.c2, (sum(ft2.c1))
+ -> Foreign Scan
+ Output: (sum(c1)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT sum("C 1"), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
+(9 rows)
+
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+ sum | c2
+-------+----
+ 49599 | 1
+ 1112 | 2
+(2 rows)
+
+select distinct sum("C 1"), c2 from "S 1"."T 1" where c2 < 6 group by c2 order by c2;
+ sum | c2
+-------+----
+ 49599 | 1
+ 1112 | 2
+(2 rows)
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE (ft1.c1 < 100)))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE (c1 < 100))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE ("C 1" < 100)), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 1
+ 450
+ 459
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+select sum("C 1") filter (where "C 1" < 100) from "S 1"."T 1" group by c2 order by 1 nulls last;
+ sum
+-----
+ 1
+ 450
+ 459
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 450
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+select sum("C 1") filter (where "C 1" < 100 and c2 > 5) from "S 1"."T 1" group by c2 order by 1 nulls last;
+ sum
+-----
+ 450
+ 480
+ 490
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+(21 rows)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft1 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft1 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+select distinct (select count(t1."C 1") filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ HashAggregate
+ Output: sum(c1) FILTER (WHERE (((c1)::double precision * random()) < '100'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+explain (verbose, costs off)
+select percentile_disc(0.25) within group (order by c2) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (percentile_disc('0.25'::double precision) WITHIN GROUP (ORDER BY c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT percentile_disc(0.25::double precision) WITHIN GROUP (ORDER BY c2 ASC NULLS LAST) FROM "S 1"."T 1"
+(4 rows)
+
+select percentile_disc(0.25) within group (order by c2) from ft1;
+ percentile_disc
+-----------------
+ 42
+(1 row)
+
+select percentile_disc(0.25) within group (order by c2) from "S 1"."T 1";
+ percentile_disc
+-----------------
+ 42
+(1 row)
+
+explain (verbose, costs off)
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont('0.5'::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, percentile_cont(0.5::double precision) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(7 rows)
+
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 501
+ 2 | 556
+ 6 | 501
+(3 rows)
+
+select c2, percentile_cont(0.5) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 501
+ 2 | 556
+ 6 | 501
+(3 rows)
+
+-- Error from foreign server
+explain (verbose, costs off)
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont((c2)::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, percentile_cont(c2) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+ERROR: percentile value 2 is not between 0 and 1
+CONTEXT: Remote SQL command: SELECT c2, percentile_cont(c2) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" GROUP BY c2
+select c2, percentile_cont(c2) within group (order by "C 1") from "S 1"."T 1" group by c2 order by c2;
+ERROR: percentile value 2 is not between 0 and 1
+explain (verbose, costs off)
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 109
+ 2 | 223
+(2 rows)
+
+select c2, percentile_cont(c2/10::numeric) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by "C 1") < 500 order by c2;
+ c2 | percentile_cont
+----+-----------------
+ 1 | 109
+ 2 | 223
+(2 rows)
+
+explain (verbose, costs off)
+select rank('10'::varchar) within group (order by c6) from ft1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (rank('10'::character varying) WITHIN GROUP (ORDER BY c6))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST) FROM "S 1"."T 1"
+(4 rows)
+
+select rank('10'::varchar) within group (order by c6) from ft1;
+ rank
+------
+ 202
+(1 row)
+
+select rank('10'::varchar) within group (order by c6) from "S 1"."T 1";
+ rank
+------
+ 202
+(1 row)
+
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY "C 1", c2
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+select "C 1", rank("C 1", c2) within group (order by "C 1", c2) from "S 1"."T 1" group by "C 1", c2 having "C 1" = 6 order by 1;
+ C 1 | rank
+-----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Add into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate with VARIADIC will be pushed
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 1 | 11
+ 2 | 1
+ 6 | 6
+ 42 | 10
+ 44 | 4
+(5 rows)
+
+select c2, least_agg("C 1") from "S 1"."T 1" where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 1 | 11
+ 2 | 1
+ 6 | 6
+ 42 | 10
+ 44 | 4
+(5 rows)
+
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR()
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as sort operator is not known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+select array_agg("C 1" order by "C 1" using operator(public.<^)) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is not known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- E. Mix aggregate tests
+-- Clauses with random() will be evaluated locally, and other clauses are pushed
+explain (verbose, costs off)
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ((ft2.c2)::double precision * random()), (NULL::bigint), ft2.c2
+ Filter: ((((sum(ft2.c1)))::double precision * random()) < '100000'::double precision)
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT NULL::bigint, c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 50000::numeric))
+(7 rows)
+
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+ count
+-------
+ 21
+(1 row)
+
+select count(*) from (select c2 * random(), count("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 100000 and avg("C 1") < 50000) x;
+ count
+-------
+ 21
+(1 row)
+
+explain (verbose, costs off)
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (sum(c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum(c2) FROM "S 1"."T 1" GROUP BY c2 HAVING (((avg(c2) + c2) < 10::numeric))
+(7 rows)
+
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+ c2 | sum
+----+-----
+ 1 | 99
+ 2 | 4
+(2 rows)
+
+select c2, sum(c2) from "S 1"."T 1" group by c2 having avg(c2) + c2 < 10 order by c2;
+ c2 | sum
+----+-----
+ 1 | 99
+ 2 | 4
+(2 rows)
+
+-- Input rel to aggregate push down hook is not safe to pushdown and thus the aggregate cannot be pushed down to foreign server
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t2
+ Remote SQL: SELECT NULL FROM "S 1"."T 1"
+ -> Materialize
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(11 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
+(20 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 1 | 1101
+ 1 | 1103
+ 1 | 1104
+ 2 | 1112
+ 2 | 2012
+ 2 | 2016
+ 2 | 2018
+ 2 | 2022
+ 2 | 2024
+ 2 | 2026
+ 2 | 2028
+ 2 | 2030
+ 2 | 2426
+ 99 | 49599
+ 100 | 49800
+ 100 | 49900
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(21 rows)
+
+select count(*), x.b from "S 1"."T 1", (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2) x where "S 1"."T 1".c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 1 | 1101
+ 1 | 1103
+ 1 | 1104
+ 2 | 1112
+ 2 | 2012
+ 2 | 2016
+ 2 | 2018
+ 2 | 2022
+ 2 | 2024
+ 2 | 2026
+ 2 | 2028
+ 2 | 2030
+ 2 | 2426
+ 99 | 49599
+ 100 | 49800
+ 100 | 49900
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(21 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+select avg(t1.c1), sum(t2.c1) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- ORDER BY expression is not present as is in target list of remote query. This needed clearing out sortgrouprefs flag.
+explain (verbose, costs off)
+select (select sum(c2)) from ft1 order by 1;
+ QUERY PLAN
+-----------------------------------------------------
+ Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Result
+ Output: (sum(ft1.c2))
+(10 rows)
+
+select (select sum(c2)) from ft1 order by 1;
+ sum
+--------
+ 199823
+(1 row)
+
+select (select sum(c2)) from "S 1"."T 1" order by 1;
+ sum
+--------
+ 199823
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Seq Scan on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Filter: (t1.c2 < 10)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(15 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ c2 | sum
+----+-----
+ 2 | 4
+ 6 | 12
+(2 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2."C 1" + t1."C 1") sum from "S 1"."T 1" t2 group by t2."C 1") qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ c2 | sum
+----+-----
+ 2 | 4
+ 6 | 12
+(2 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select count(ft4.c1), sum(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(ft4.c1)), (sum(q.b)), q.b
+ Sort Key: (count(ft4.c1))
+ -> GroupAggregate
+ Output: count(ft4.c1), sum(q.b), q.b
+ Group Key: q.b
+ -> Sort
+ Output: q.b, ft4.c1
+ Sort Key: q.b
+ -> Hash Left Join
+ Output: q.b, ft4.c1
+ Hash Cond: ((ft4.c1)::numeric = q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Hash
+ Output: q.b
+ -> Subquery Scan on q
+ Output: q.b
+ -> Aggregate
+ Output: NULL::integer, avg(ft1.c1), NULL::bigint
+ -> Foreign Scan
+ Output: ft1.c1
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r1."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
+(25 rows)
+
+select count(ft4.c1), sum(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1;
+ count | sum
+-------+-----
+ 3 |
+(1 row)
+
+select count(t4.c1), sum(q.b) from "S 1"."T 3" t4 left join (select 13, avg(t1."C 1"), sum(t2."C 1") from "S 1"."T 1" t1 right join "S 1"."T 1" t2 on (t1."C 1" = t2."C 1") where t1."C 1" = 12) q(a, b, c) on (t4.c1 = q.b) where t4.c1 between 10 and 15 group by q.b order by 1;
+ count | sum
+-------+-----
+ 3 |
+(1 row)
+
+explain (verbose, costs off)
+select q.a, count(q.a), avg(ft2.c1) from (select 13 from ft1 where c1 = 13) q(a) right join ft2 on (q.a = ft2.c1) where ft2.c1 between 10 and 15 group by q.a order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: (13), count((13)), avg(ft2.c1)
+ Group Key: (13)
+ -> Sort
+ Output: (13), ft2.c1
+ Sort Key: (13)
+ -> Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(17 rows)
+
+select q.a, count(q.a), avg(ft2.c1) from (select 13 from ft1 where c1 = 13) q(a) right join ft2 on (q.a = ft2.c1) where ft2.c1 between 10 and 15 group by q.a order by 1 nulls last;
+ a | count | avg
+----+-------+---------------------
+ 13 | 1 | 13.0000000000000000
+ | 0 | 11.6666666666666667
+(2 rows)
+
+select q.a, count(q.a), avg("S 1"."T 1"."C 1") from (select 13 from "S 1"."T 1" where "C 1" = 13) q(a) right join "S 1"."T 1" on (q.a = "S 1"."T 1"."C 1") where "S 1"."T 1"."C 1" between 10 and 15 group by q.a order by 1 nulls last;
+ a | count | avg
+----+-------+---------------------
+ 13 | 1 | 13.0000000000000000
+ | 0 | 11.6666666666666667
+(2 rows)
+
+-- F. Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+-------
+ 1 | 49599
+ 2 | 1112
+ | 50711
+(3 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+-------
+ 1 | 49599
+ 2 | 1112
+ | 50711
+(3 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+-------
+ 1 | 49599
+ 2 | 1112
+ | 50711
+(3 rows)
+
+select c2, sum("C 1") from "S 1"."T 1" where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+-------
+ 1 | 49599
+ 2 | 1112
+ | 50711
+(3 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> GroupAggregate
+ Output: c2, c6, sum(c1)
+ Group Key: ft1.c2
+ Sort Key: ft1.c6
+ Group Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 1 | | 49599
+ 2 | | 1112
+ | 1 | 49600
+ | | 1111
+(4 rows)
+
+select c2, c6, sum("C 1") from "S 1"."T 1" where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 1 | | 49599
+ 2 | | 1112
+ | 1 | 49600
+ | | 1111
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 1 | 49599 | 0
+ 2 | 1112 | 0
+(2 rows)
+
+select c2, sum("C 1"), grouping(c2) from "S 1"."T 1" where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 1 | 49599 | 0
+ 2 | 1112 | 0
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 order by 1 limit 5 offset 95;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Limit
+ Output: c2, (count(c2) OVER (?)), ((c2 % 2))
+ -> Sort
+ Output: c2, (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: ((c2 % 2)), c2
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan on public.ft2
+ Output: (c2 % 2), c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 10))
+(13 rows)
+
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 order by 1 limit 5 offset 95;
+ c2 | count
+----+-------
+ 1 | 99
+ 1 | 99
+ 1 | 99
+ 1 | 99
+ 2 | 102
+(5 rows)
+
+select c2, count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 order by 1 limit 5 offset 95;
+ c2 | count
+----+-------
+ 1 | 99
+ 1 | 99
+ 1 | 99
+ 1 | 99
+ 2 | 102
+(5 rows)
+
+explain (verbose, costs off)
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | count
+----+-------
+ 1 | 1
+ 2 | 2
+ 6 | 2
+(3 rows)
+
+select c2, count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ c2 | count
+----+-------
+ 1 | 1
+ 2 | 2
+ 6 | 2
+(3 rows)
+
+explain (verbose, costs off)
+select c2, sum(c2) over (partition by c2%2 order by c2) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, sum(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, sum(c2) over (partition by c2%2 order by c2) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | sum
+----+-----
+ 1 | 1
+ 2 | 2
+ 6 | 8
+(3 rows)
+
+select c2, sum(c2) over (partition by c2%2 order by c2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ c2 | sum
+----+-----
+ 1 | 1
+ 2 | 2
+ 6 | 8
+(3 rows)
+
+explain (verbose, costs off)
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, sum(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | sum
+----+-----
+ 1 | 1
+ 2 | 8
+ 6 | 6
+(3 rows)
+
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ c2 | sum
+----+-----
+ 1 | 1
+ 2 | 8
+ 6 | 6
+(3 rows)
+
+explain (verbose, costs off)
+select sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c2)), (count(c2) OVER (?)), c2, ((c2 % 2))
+ Sort Key: (sum(ft2.c2))
+ -> WindowAgg
+ Output: (sum(c2)), count(c2) OVER (?), c2, ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ sum | count
+-----+-------
+ 4 | 2
+ 99 | 1
+ 600 | 2
+(3 rows)
+
+select sum(c2), count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+ sum | count
+-----+-------
+ 4 | 2
+ 99 | 1
+ 600 | 2
+(3 rows)
+
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..05b2189 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -24,7 +24,9 @@
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "nodes/print.h"
#include "optimizer/cost.h"
+#include "optimizer/clauses.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
@@ -38,6 +40,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/sampling.h"
+#include "utils/selfuncs.h"
PG_MODULE_MAGIC;
@@ -343,6 +346,10 @@ static void postgresGetForeignJoinPaths(PlannerInfo *root,
JoinPathExtraData *extra);
static bool postgresRecheckForeignScan(ForeignScanState *node,
TupleTableSlot *slot);
+static void postgresGetForeignUpperPaths(PlannerInfo *root,
+ UpperRelationKind stage,
+ RelOptInfo *input_rel,
+ RelOptInfo *output_rel);
/*
* Helper functions
@@ -400,12 +407,15 @@ static void conversion_error_callback(void *arg);
static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel,
JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinPathExtraData *extra);
+static bool foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel);
static List *get_useful_pathkeys_for_relation(PlannerInfo *root,
RelOptInfo *rel);
static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel);
static void add_paths_with_pathkeys_for_rel(PlannerInfo *root, RelOptInfo *rel,
Path *epq_path);
-
+static void add_foreign_grouping_paths(PlannerInfo *root,
+ RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel);
/*
* Foreign-data wrapper handler function: return a struct with pointers
@@ -455,6 +465,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
/* Support functions for join push-down */
routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+ /* Support functions for upper relation push-down */
+ routine->GetForeignUpperPaths = postgresGetForeignUpperPaths;
+
PG_RETURN_POINTER(routine);
}
@@ -1120,7 +1133,7 @@ postgresGetForeignPlan(PlannerInfo *root,
* rel->baserestrictinfo + parameterization clauses through
* scan_clauses. For a join rel->baserestrictinfo is NIL and we are
* not considering parameterization right now, so there should be no
- * scan_clauses for a joinrel.
+ * scan_clauses for a joinrel and upper rel either.
*/
Assert(!scan_clauses);
}
@@ -1170,7 +1183,8 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1191,6 +1205,13 @@ postgresGetForeignPlan(PlannerInfo *root,
{
ListCell *lc;
+ /*
+ * Right now, we only consider grouping and aggregation beyond
+ * joins. Queries involving aggregates or grouping do not require
+ * EPQ mechanism, hence should not have an outer plan here.
+ */
+ Assert(foreignrel->reloptkind != RELOPT_UPPER_REL);
+
outer_plan->targetlist = fdw_scan_tlist;
foreach(lc, local_exprs)
@@ -1228,7 +1249,8 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2452,7 +2474,8 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
/*
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
- * either a base relation or a join between foreign relations.
+ * either a base relation or a join between foreign relations or an upper
+ * relation containing foreign relations.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -2505,7 +2528,8 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,25 +2610,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
- {
- /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
- retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
-
- /*
- * Cost as though this were a seqscan, which is pessimistic. We
- * effectively imagine the local_conds are being evaluated
- * remotely, too.
- */
- startup_cost = 0;
- run_cost = 0;
- run_cost += seq_page_cost * foreignrel->pages;
-
- startup_cost += foreignrel->baserestrictcost.startup;
- cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
- run_cost += cpu_per_tuple * foreignrel->tuples;
- }
- else
+ else if (foreignrel->reloptkind == RELOPT_JOINREL)
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
@@ -2670,6 +2676,97 @@ estimate_path_cost_size(PlannerInfo *root,
run_cost += nrows * remote_conds_cost.per_tuple;
run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows;
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+ AggClauseCosts aggcosts;
+ double input_rows;
+ int numGroupCols;
+ double numGroups = 1;
+
+ /*
+ * This cost model is mixture of costing done for sorted and hashed
+ * aggregates in cost_agg(). We are not sure which strategy will
+ * be considered at remote side, thus for simplicity, we put all
+ * startup related costs in startup_cost and all finalization and
+ * run cost are added in total_cost.
+ *
+ * Also, core does not care about costing HAVING expressions and
+ * adding that to the costs. So similarly, here too we are not
+ * considering remote and local conditions for costing.
+ */
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /* Get rows and width from input rel */
+ input_rows = ofpinfo->rows;
+ width = ofpinfo->width;
+
+ /* Collect statistics about aggregates for estimating costs. */
+ MemSet(&aggcosts, 0, sizeof(AggClauseCosts));
+ if (root->parse->hasAggs)
+ {
+ get_agg_clause_costs(root, (Node *) fpinfo->grouped_tlist,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ get_agg_clause_costs(root, (Node *) root->parse->havingQual,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ }
+
+ /* Get number of grouping columns and possible number of groups */
+ numGroupCols = list_length(root->parse->groupClause);
+ numGroups = estimate_num_groups(root,
+ get_sortgrouplist_exprs(root->parse->groupClause,
+ fpinfo->grouped_tlist),
+ input_rows, NULL);
+
+ /*
+ * Number of rows expected from foreign server will be same as that
+ * of number of groups.
+ */
+ rows = retrieved_rows = numGroups;
+
+ /*
+ * Startup cost includes:
+ * 1. Startup cost for underneath input relation
+ * 2. Cost of performing aggregation, per cost_agg()
+ * 3. Startup cost for PathTarget eval
+ */
+ startup_cost = ofpinfo->rel_startup_cost;
+ startup_cost += aggcosts.transCost.startup;
+ startup_cost += aggcosts.transCost.per_tuple * input_rows;
+ startup_cost += (cpu_operator_cost * numGroupCols) * input_rows;
+ startup_cost += ptarget->cost.startup;
+
+ /*
+ * Run time cost includes:
+ * 1. Run time cost of underneath input relation
+ * 2. Run time cost of performing aggregation, per cost_agg()
+ * 4. PathTarget eval cost for each output row
+ */
+ run_cost = ofpinfo->rel_total_cost - ofpinfo->rel_startup_cost;
+ run_cost += aggcosts.finalCost * numGroups;
+ run_cost += cpu_tuple_cost * numGroups;
+ run_cost += ptarget->cost.per_tuple * numGroups;
+ }
+ else
+ {
+ /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
+ retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
+
+ /*
+ * Cost as though this were a seqscan, which is pessimistic. We
+ * effectively imagine the local_conds are being evaluated
+ * remotely, too.
+ */
+ startup_cost = 0;
+ run_cost = 0;
+ run_cost += seq_page_cost * foreignrel->pages;
+
+ startup_cost += foreignrel->baserestrictcost.startup;
+ cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
+ run_cost += cpu_per_tuple * foreignrel->tuples;
+ }
/*
* Without remote estimates, we have no real way to estimate the cost
@@ -4343,6 +4440,331 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
}
/*
+ * Assess whether the aggregation, grouping and having operations can be pushed
+ * down to the foreign server. As a side effect, save information we obtain in
+ * this function to PgFdwRelationInfo of the input relation.
+ */
+static bool
+foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
+{
+ Query *query = root->parse;
+ PathTarget *grouping_target;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) grouped_rel->fdw_private;
+ PgFdwRelationInfo *ofpinfo;
+ List *aggvars;
+ ListCell *lc;
+ int i;
+ List *tlist = NIL;
+
+ /* Grouping Sets are not pushable */
+ if (query->groupingSets)
+ return false;
+
+ /* Get the fpinfo of the underlying scan relation. */
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /*
+ * If underneath input relation has any local conditions, those conditions
+ * are required to be applied before performing aggregation. Hence the
+ * aggregate cannot be pushed down.
+ */
+ if (ofpinfo->local_conds)
+ return false;
+
+ /*
+ * We may need to modify the sortgrouprefs from path target, thus copy it
+ * so that we will not have any undesired effect. We need to modify the
+ * sortgrouprefs when it points to one of the ORDER BY expression but not
+ * to any GROUP BY expression and that expression is not pushed as is. If
+ * we do not clear such entries, then we will end up into an error.
+ */
+ grouping_target = copy_pathtarget(root->upper_targets[UPPERREL_GROUP_AGG]);
+
+ /*
+ * Evaluate grouping targets and check whether they are safe to push down
+ * to the foreign side. All GROUP BY expressions will be part of the
+ * grouping target and thus there is no need to evaluate it separately.
+ * While doing so, add required expressions into target list which
+ * can then be used to pass to foreign server.
+ */
+ i = 0;
+ foreach(lc, grouping_target->exprs)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+ Index sgref = get_pathtarget_sortgroupref(grouping_target, i);
+ ListCell *l;
+
+ /* Check whether this expression is part of GROUP BY clause */
+ if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause))
+ {
+ /*
+ * If any of the GROUP BY expression is not shippable we can not
+ * push down aggregation to the foreign server.
+ */
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* Check entire expression whether it is pushable or not */
+ if (is_foreign_expr(root, grouped_rel, expr))
+ {
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /*
+ * If we have sortgroupref set, then it means that we have an
+ * ORDER BY entry pointing to this expression. Since we are
+ * not pushing ORDER BY with GROUP BY, clear it.
+ */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
+
+ /* Not matched exactly, pull the var with aggregates then */
+ aggvars = pull_var_clause((Node *) expr,
+ PVC_INCLUDE_AGGREGATES);
+
+ if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars))
+ return false;
+
+ /*
+ * Add aggregates, if any, into the targetlist. Plain var
+ * nodes either be same as some GROUP BY expression or part of
+ * some GROUP BY expression. In later case, the query cannot
+ * refer plain var nodes without the surrounding expression.
+ * In both the cases, they are already part of the targetlist
+ * and thus no need to add them again. In fact adding pulled
+ * plain var nodes in SELECT clause will cause an error on the
+ * foreign server if they are not same as some GROUP BY
+ * expression.
+ */
+ foreach(l, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(l);
+
+ if (IsA(expr, Aggref))
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ }
+ }
+
+ i++;
+ }
+
+ /*
+ * Classify the pushable and non-pushable having clauses and save them in
+ * remote_conds and local_conds of grouped_rel::fpinfo.
+ */
+ if (root->hasHavingQual && query->havingQual)
+ {
+ ListCell *lc;
+
+ foreach(lc, (List *) query->havingQual)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
+ else
+ fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
+ }
+ }
+
+ /*
+ * If there are any local conditions, pull Vars and aggregates from it and
+ * check whether they are safe to pushdown or not.
+ */
+ if (fpinfo->local_conds)
+ {
+ ListCell *lc;
+ List *aggvars = pull_var_clause((Node *) fpinfo->local_conds,
+ PVC_INCLUDE_AGGREGATES);
+
+ foreach(lc, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ /*
+ * If aggregates within local conditions are not safe to push down,
+ * then we cannot push down the query. Vars are already part of
+ * GROUP BY clause which are checked above, so no need to access
+ * them again here.
+ */
+ if (IsA(expr, Aggref) && !is_foreign_expr(root, grouped_rel, expr))
+ return false;
+ }
+
+ /* Add Vars and aggregates into the target list. */
+ tlist = add_to_flat_tlist(tlist, aggvars);
+ }
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, grouping_target);
+ /* Store generated targetlist */
+ fpinfo->grouped_tlist = tlist;
+
+ /* Safe to pushdown */
+ fpinfo->pushdown_safe = true;
+
+ /*
+ * If user is willing to estimate cost for a scan using EXPLAIN, he intends
+ * to estimate scans on that relation more accurately. Then, it makes sense
+ * to estimate the cost of the grouping on that relation more accurately
+ * using EXPLAIN.
+ */
+ fpinfo->use_remote_estimate = ofpinfo->use_remote_estimate;
+
+ /* Copy startup and tuple cost as is from underneath input rel's fpinfo */
+ fpinfo->fdw_startup_cost = ofpinfo->fdw_startup_cost;
+ fpinfo->fdw_tuple_cost = ofpinfo->fdw_tuple_cost;
+
+ /*
+ * Set cached relation costs to some negative value, so that we can detect
+ * when they are set to some sensible costs, during one (usually the
+ * first) of the calls to estimate_path_cost_size().
+ */
+ fpinfo->rel_startup_cost = -1;
+ fpinfo->rel_total_cost = -1;
+
+ /* Set fetch size same as that of underneath input rel's fpinfo */
+ fpinfo->fetch_size = ofpinfo->fetch_size;
+
+ /*
+ * Set the string describing this grouped relation to be used in EXPLAIN
+ * output of corresponding ForeignScan.
+ */
+ fpinfo->relation_name = makeStringInfo();
+ appendStringInfo(fpinfo->relation_name, "Aggregate on (%s)",
+ ofpinfo->relation_name->data);
+
+ return true;
+}
+
+/*
+ * postgresGetForeignUpperPaths
+ * Add paths for post-join operations like aggregation, grouping etc. if
+ * corresponding operations are safe to push down.
+ *
+ * Right now, we only support aggregate, grouping and having clause pushdown.
+ */
+static void
+postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
+ RelOptInfo *input_rel, RelOptInfo *output_rel)
+{
+ PgFdwRelationInfo *fpinfo;
+
+ /*
+ * If input rel is not safe to pushdown, then simply return as we cannot
+ * perform any post-join operations remotely on it.
+ */
+ if (!input_rel->fdw_private ||
+ !((PgFdwRelationInfo *) input_rel->fdw_private)->pushdown_safe)
+ return;
+
+ /*
+ * This should not happen normally. In case we have already added paths for
+ * this output rel, nothing to be done again.
+ */
+ if (output_rel->fdw_private)
+ return;
+
+ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+ fpinfo->pushdown_safe = false;
+ output_rel->fdw_private = fpinfo;
+
+ if (stage == UPPERREL_GROUP_AGG)
+ return add_foreign_grouping_paths(root, input_rel, output_rel);
+
+ /* If it's anything else, we are not adding any foreign path. */
+ return;
+}
+
+/*
+ * add_foreign_grouping_paths
+ * Add foreign path for grouping and/or aggregation.
+ *
+ * Given input_rel represents the underlying scan. The paths are added to the
+ * given grouped_rel.
+ */
+static void
+add_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel)
+{
+ Query *parse = root->parse;
+ PgFdwRelationInfo *ifpinfo = input_rel->fdw_private;
+ PgFdwRelationInfo *fpinfo = grouped_rel->fdw_private;
+ ForeignPath *grouppath;
+ PathTarget *grouping_target;
+ double rows;
+ int width;
+ Cost startup_cost;
+ Cost total_cost;
+
+ /* Nothing to be done, if there is no grouping or aggregation required. */
+ if (!parse->groupClause && !parse->groupingSets && !parse->hasAggs &&
+ !root->hasHavingQual)
+ return;
+
+ grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /*
+ * We need relids to deparse column references from target list.
+ * FIXME: Is this a correct place to copy relids from underneath input_rel
+ * to the grouped_rel for which we are adding a path here? Or this should
+ * have been already set by core itself?
+ */
+ grouped_rel->relids = bms_copy(input_rel->relids);
+
+ /* save the input_rel as outerrel in fpinfo */
+ fpinfo->outerrel = input_rel;
+
+ /*
+ * Copy foreign table, foreign server, user mapping, shippable extensions
+ * etc. details from underneath input relation's fpinfo.
+ */
+ fpinfo->table = ifpinfo->table;
+ fpinfo->server = ifpinfo->server;
+ fpinfo->user = ifpinfo->user;
+ fpinfo->shippable_extensions = ifpinfo->shippable_extensions;
+
+ /* Assess if it is safe to push down aggregation and grouping. */
+ if (!foreign_grouping_ok(root, grouped_rel))
+ return;
+
+ /* Estimate the cost of push down */
+ estimate_path_cost_size(root, grouped_rel, NIL, NIL, &rows,
+ &width, &startup_cost, &total_cost);
+
+ /* Now update this information in the fpinfo */
+ fpinfo->rows = rows;
+ fpinfo->width = width;
+ fpinfo->startup_cost = startup_cost;
+ fpinfo->total_cost = total_cost;
+
+ /* Create and add foreign path to the grouping relation. */
+ grouppath = create_foreignscan_path(root,
+ grouped_rel,
+ grouping_target,
+ rows,
+ startup_cost,
+ total_cost,
+ NIL, /* no pathkeys */
+ NULL, /* no required_outer */
+ NULL,
+ NULL); /* no fdw_private */
+
+ /* Add generated path into grouped_rel by add_path(). */
+ add_path(grouped_rel, (Path *) grouppath);
+
+ return;
+}
+
+/*
* Create a tuple from the specified row of the PGresult.
*
* rel is the local representation of the foreign table, attinmeta is
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 67126bc..f8c255e 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -92,6 +92,9 @@ typedef struct PgFdwRelationInfo
RelOptInfo *innerrel;
JoinType jointype;
List *joinclauses;
+
+ /* Grouping information */
+ List *grouped_tlist;
} PgFdwRelationInfo;
/* in postgres_fdw.c */
@@ -155,7 +158,7 @@ extern void deparseAnalyzeSql(StringInfo buf, Relation rel,
List **retrieved_attrs);
extern void deparseStringLiteral(StringInfo buf, const char *val);
extern Expr *find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel);
-extern List *build_tlist_to_deparse(RelOptInfo *foreign_rel);
+extern List *build_tlist_to_deparse(RelOptInfo *foreignrel);
extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, List *tlist,
List *remote_conds, List *pathkeys,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f68e89..b79e08f 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -1356,3 +1356,433 @@ WHERE ftrelid = 'table30000'::regclass
AND ftoptions @> array['fetch_size=60000'];
ROLLBACK;
+
+
+-- Test Aggregate Push Down
+-- Both ft1 and ft2 are used to exercise cost estimates when
+-- use_remote_estimate is false and true respectively.
+
+-- A. Simple aggregates
+explain (verbose, costs off)
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+select sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1;
+select sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2) from "S 1"."T 1";
+
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+
+explain (verbose, costs off)
+select count(c6) from ft1;
+select count(c6) from ft1;
+select count(c6) from "S 1"."T 1";
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+select sum(c1) from ft2 where c2 < 5;
+select sum("C 1") from "S 1"."T 1" where c2 < 5;
+
+explain (verbose, costs off)
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select sum(t1."C 1"), avg(t1."C 1") from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+select count(*) from "S 1"."T 1" t1 inner join "S 1"."T 1" t2 on (t1.c2 = t2.c2) where t2.c2 = 6;
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
+
+
+-- B. Aggregates with GROUP BY
+explain (verbose, costs off)
+select c2, count(*) from ft1 group by c2 order by 1;
+select c2, count(*) from ft1 group by c2 order by 1;
+select c2, count(*) from "S 1"."T 1" group by c2 order by 1;
+
+explain (verbose, costs off)
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+select count(c1), length(c6) from ft2 group by c6 order by 1, 2;
+select count("C 1"), length(c6) from "S 1"."T 1" group by c6 order by 1, 2;
+
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from "S 1"."T 1" group by c2/2 order by c2/2;
+
+explain (verbose, costs off)
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(a), sum(a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(a), sum(a) from (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2, sqrt("C 1") order by 1, 2) x;
+
+-- Aggregate is still pushed down by taking random() out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select "C 1" * random(), sum("C 1") * "C 1" from "S 1"."T 1" group by "C 1";
+
+-- Aggregate is not pushed down as random() is part of group by expression
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+
+explain (verbose, costs off)
+select count(c2), 5 from ft1 group by 2;
+select count(c2), 5 from ft1 group by 2;
+select count(c2), 5 from "S 1"."T 1" group by 2;
+
+explain (verbose, costs off)
+select count(c2) a, 5.0 b from ft1 group by b;
+select count(c2) a, 5.0 b from ft1 group by b;
+select count(c2) a, 5.0 b from "S 1"."T 1" group by b;
+
+explain (verbose, costs off)
+select count(c2) from ft1 group by 5::int;
+select count(c2) from ft1 group by 5::int;
+select count(c2) from "S 1"."T 1" group by 5::int;
+
+
+-- C. Aggregates with HAVING clause
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 order by 1;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 order by 1;
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+select c2, sum(c1) from ft1 group by c2 having avg(c1) < 500 and sum(c1) < 200000 order by c2;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having avg("C 1") < 500 and sum("C 1") < 200000 order by c2;
+
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+select c5, count(c2) from "S 1"."T 1" group by c5, sqrt(c2) having sqrt(max(c2)) < 2 order by 1, 2;
+
+-- Having clause with random() will be evaluated locally
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() < 500000 order by c2;
+select c2, sum("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 500000 order by c2;
+
+-- Having clause with random() will be evaluated locally, and other having qual is pushed
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+select count(*) from (select c5, count("C 1") from "S 1"."T 1" group by c5, sqrt(c2) having avg("C 1") * random() < 500 and avg("C 1") < 500) x;
+
+-- Aggregate in having clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * random()) > 100;
+
+
+-- D. ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+explain (verbose, costs off)
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+select array_agg(c1 order by c3) from ft1 where c2 = 6 and c1 < 100;
+select array_agg("C 1" order by c3) from "S 1"."T 1" where c2 = 6 and "C 1" < 100;
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+select array_agg(c1 order by c1) from ft2 where c1 < 100 group by c2 order by 1;
+select array_agg("C 1" order by "C 1") from "S 1"."T 1" where "C 1" < 100 group by c2 order by 1;
+
+explain (verbose, costs off)
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 desc) from ft1 where c2 = 6 and c1 < 100 group by c2;
+select array_agg("C 1" order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by "C 1" desc) from "S 1"."T 1" where c2 = 6 and "C 1" < 50;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum(c1%3), sum(distinct c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum("C 1"%3), sum(distinct "C 1"%3) filter (where "C 1"%3 < 2), c2 from "S 1"."T 1" where c2 = 6 group by c2;
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
+select distinct sum("C 1"), c2 from "S 1"."T 1" where c2 < 6 group by c2 order by c2;
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100) from ft1 group by c2 order by 1 nulls last;
+select sum("C 1") filter (where "C 1" < 100) from "S 1"."T 1" group by c2 order by 1 nulls last;
+
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum("C 1") filter (where "C 1" < 100 and c2 > 5) from "S 1"."T 1" group by c2 order by 1 nulls last;
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
+select distinct (select count(t1."C 1") filter (where t2.c2 = 6 and t2."C 1" < 10) from "S 1"."T 1" t1 where t1."C 1" = 6) from "S 1"."T 1" t2 order by 1;
+
+-- Aggregate not pushed down
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+
+explain (verbose, costs off)
+select percentile_disc(0.25) within group (order by c2) from ft1;
+select percentile_disc(0.25) within group (order by c2) from ft1;
+select percentile_disc(0.25) within group (order by c2) from "S 1"."T 1";
+
+explain (verbose, costs off)
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, percentile_cont(0.5) within group (order by c1) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, percentile_cont(0.5) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+
+-- Error from foreign server
+explain (verbose, costs off)
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+select c2, percentile_cont(c2) within group (order by c1) from ft1 group by c2 order by c2;
+select c2, percentile_cont(c2) within group (order by "C 1") from "S 1"."T 1" group by c2 order by c2;
+
+explain (verbose, costs off)
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, percentile_cont(c2/10::numeric) within group (order by "C 1") from "S 1"."T 1" where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by "C 1") < 500 order by c2;
+
+explain (verbose, costs off)
+select rank('10'::varchar) within group (order by c6) from ft1;
+select rank('10'::varchar) within group (order by c6) from ft1;
+select rank('10'::varchar) within group (order by c6) from "S 1"."T 1";
+
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+select "C 1", rank("C 1", c2) within group (order by "C 1", c2) from "S 1"."T 1" group by "C 1", c2 having "C 1" = 6 order by 1;
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Add into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now aggregate with VARIADIC will be pushed
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg("C 1") from "S 1"."T 1" where c2 < 100 group by c2 order by c2;
+
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+
+
+-- Testing USING OPERATOR()
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+
+create operator family my_op_family using btree;
+
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+
+-- This will not be pushed as sort operator is not known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now this will be pushed as sort operator is known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+select array_agg("C 1" order by "C 1" using operator(public.<^)) from "S 1"."T 1" where c2 = 6 and "C 1" < 100 group by c2;
+
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- This will not be pushed as sort operator is not known to extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+
+
+-- E. Mix aggregate tests
+-- Clauses with random() will be evaluated locally, and other clauses are pushed
+explain (verbose, costs off)
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+select count(*) from (select c2 * random(), count(c1) from ft2 group by c2 having sum(c1) * random() < 100000 and avg(c1) < 50000) x;
+select count(*) from (select c2 * random(), count("C 1") from "S 1"."T 1" group by c2 having sum("C 1") * random() < 100000 and avg("C 1") < 50000) x;
+
+explain (verbose, costs off)
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+select c2, sum(c2) from ft1 group by c2 having avg(c2) + c2 < 10 order by c2;
+select c2, sum(c2) from "S 1"."T 1" group by c2 having avg(c2) + c2 < 10 order by c2;
+
+-- Input rel to aggregate push down hook is not safe to pushdown and thus the aggregate cannot be pushed down to foreign server
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from "S 1"."T 1", (select c2 a, sum("C 1") b from "S 1"."T 1" group by c2) x where "S 1"."T 1".c2 = x.a group by x.b order by 1, 2;
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+select avg(t1.c1), sum(t2.c1) from "S 1"."T 3" t1 full join "S 1"."T 4" t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+
+-- ORDER BY expression is not present as is in target list of remote query. This needed clearing out sortgrouprefs flag.
+explain (verbose, costs off)
+select (select sum(c2)) from ft1 order by 1;
+select (select sum(c2)) from ft1 order by 1;
+select (select sum(c2)) from "S 1"."T 1" order by 1;
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2."C 1" + t1."C 1") sum from "S 1"."T 1" t2 group by t2."C 1") qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select count(ft4.c1), sum(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1;
+select count(ft4.c1), sum(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1;
+select count(t4.c1), sum(q.b) from "S 1"."T 3" t4 left join (select 13, avg(t1."C 1"), sum(t2."C 1") from "S 1"."T 1" t1 right join "S 1"."T 1" t2 on (t1."C 1" = t2."C 1") where t1."C 1" = 12) q(a, b, c) on (t4.c1 = q.b) where t4.c1 between 10 and 15 group by q.b order by 1;
+
+explain (verbose, costs off)
+select q.a, count(q.a), avg(ft2.c1) from (select 13 from ft1 where c1 = 13) q(a) right join ft2 on (q.a = ft2.c1) where ft2.c1 between 10 and 15 group by q.a order by 1 nulls last;
+select q.a, count(q.a), avg(ft2.c1) from (select 13 from ft1 where c1 = 13) q(a) right join ft2 on (q.a = ft2.c1) where ft2.c1 between 10 and 15 group by q.a order by 1 nulls last;
+select q.a, count(q.a), avg("S 1"."T 1"."C 1") from (select 13 from "S 1"."T 1" where "C 1" = 13) q(a) right join "S 1"."T 1" on (q.a = "S 1"."T 1"."C 1") where "S 1"."T 1"."C 1" between 10 and 15 group by q.a order by 1 nulls last;
+
+
+-- F. Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+select c2, sum("C 1") from "S 1"."T 1" where c2 < 3 group by rollup(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+select c2, sum("C 1") from "S 1"."T 1" where c2 < 3 group by cube(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+select c2, c6, sum("C 1") from "S 1"."T 1" where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+select c2, sum("C 1"), grouping(c2) from "S 1"."T 1" where c2 < 3 group by c2 order by 1 nulls last;
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 order by 1 limit 5 offset 95;
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 order by 1 limit 5 offset 95;
+select c2, count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 order by 1 limit 5 offset 95;
+explain (verbose, costs off)
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select c2, count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, sum(c2) over (partition by c2%2 order by c2) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2) over (partition by c2%2 order by c2) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2) over (partition by c2%2 order by c2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select sum(c2), count(c2) over (partition by c2%2) from "S 1"."T 1" where c2 < 10 group by c2 order by 1;
On Mon, Sep 12, 2016 at 5:19 PM, Jeevan Chalke <
jeevan.chalke@enterprisedb.com> wrote:
On Mon, Sep 12, 2016 at 12:20 PM, Prabhat Sahu <
prabhat.sahu@enterprisedb.com> wrote:Hi,
While testing "Aggregate pushdown", i found the below error:
-- GROUP BY alias showing different behavior after adding patch.-- Create table "t1", insert few records.
create table t1(c1 int);
insert into t1 values(10), (20);-- Create foreign table:
create foreign table f_t1 (c1 int) server db1_server options (table_name
't1');-- with local table:
postgres=# select 2 a, avg(c1) from t1 group by a;
a | avg
---+---------------------
2 | 15.0000000000000000
(1 row)-- with foreign table:
postgres=# select 2 a, avg(c1) from f_t1 group by a;
ERROR: aggregate functions are not allowed in GROUP BY
CONTEXT: Remote SQL command: EXPLAIN SELECT 2, avg(c1) FROM public.t1
GROUP BY 2Thanks for reporting this bug in *v1.patch Prabhat.
I will have a look over this issue and will post a fix in next version.
To fix this issue, we need to make deparseConst() function aware of showtype
flag exactly as that of get_const_expr(). While deparsing Const in GROUP BY
clause, we need to show "::typename" so that it won't treat the constant
value
as a column position in the target list and rather treat it as constant
value.
Fixed this in earlier attached patch and added test-case too.
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Fri, Sep 16, 2016 at 9:45 AM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
6. Per my understanding, I think checking for just aggregate function is
enough as we are interested in whole aggregate result.
+1.
Meanwhile I will
check whether we need to find and check shippability of transition,
combination and finalization functions or not.
I don't think that'd be appropriate. The user is calling the
aggregate, not its constituent functions.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Thanks Jeevan for working on the comments.
3. classifyConditions() assumes list expressions of type RestrictInfo. But
HAVING clause expressions (and JOIN conditions) are plain expressions. Do
you mean we should modify the classifyConditions()? If yes, then I think it
should be done as a separate (cleanup) patch.
Ok. Yes, we should also handle bare conditions in
classifyConditions(). I am fine doing it as a separate patch.
6. Per my understanding, I think checking for just aggregate function is
enough as we are interested in whole aggregate result. Meanwhile I will
check whether we need to find and check shippability of transition,
combination and finalization functions or not.
Ok. I agree with this analysis.
13. Fixed. However instead of adding new function made those changes inline.
Adding support for deparsing List expressions separating list by comma can
be
considered as cleanup patch as it will touch other code area not specific to
aggregate push down.
Ok.
18. I think re-factoring estimate_path_cost_size() should be done separately
as a cleanup patch too.
Ok.
29. I have tried passing input rel's relids to fetch_upper_rel() call in
create_grouping_paths(). It solved this patch's issue, but ended up with
few regression failures which is mostly plan changes. I am not sure whether
we get good plan now or not as I have not analyzed them.
So for this patch, I am setting relids in add_foreign_grouping_path()
itself.
However as suggested, used bms_copy(). I still kept the FIXME over there as
I think it should have done by the core itself.
I don't think add_foreign_grouping_path() is the right place to change
a structure managed by the core and esp when we are half-way adding
paths. An FDW should not meddle with an upper RelOptInfo. Since
create_foreignscan_plan() picks those up from RelOptInfo and both of
those are part of core, we need a place in core to set the
RelOptInfo::relids for an upper relation OR we have stop using
fs_relids for upper relation foreign scans.
Here are some more comments on the patch, mostly focused on the tests.
1. If we dig down each usage of deparse_expr_cxt::scanrel, it boils down
checking whether a given Var comes from given scan relation (deparseVar()) or
checking whether a given Var needs relation qualification while deparsing
(again deparseVar()). I think both of those purposes can be served by looking
at scanrel::relids, multiple relids implying relation qualification. So,
instead of having a separate member scan_rel, we should instead fetch the
relids from deparse_expr_cxt::foreignrel. I am assuming that the proposed
change to set relids in upper relations is acceptable. If it's not, we should
pass scanrel->relids through the context instead of scanrel itself.
2. SortGroupClause is a parser node, so we can name appendSortGroupClause() as
deparseSortGroupClause(), to be consistent with the naming convention. If we do
that change, may be it's better to pass SortGroupClause as is and handle other
members of that structure as well.
3. Following block may be reworded
+ /*
+ * aggorder too present into args so no need to check its
+ * shippability explicitly. However, if any expression has
+ * USING clause with sort operator, we need to make sure the
+ * shippability of that operator.
+ */
as "For aggorder elements, check whether the sort operator, if specified, is
shippable or not." and mention aggorder expression along with aggdirectargs in
the comment before this one.
4. Following line is correct as long as there is only one upper relation.
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ?
fpinfo->outerrel : rel;
But as we push down more and more of upper operation, there will be a chain of
upper relations on top of scan relation. So, it's better to assert that the
scanrel is a join or a base relation to be future proof.
5. In deparseConst(), showtype is compared with hardcoded values. The
callers of this function pass hardcoded values. Instead, we should
define an enum and use it. I understand that this logic has been borrowed from
get_const_expr(), which also uses hardcoded values. Any reason why not to adopt
a better style here? In fact, it only uses two states for showtype, 0 and ">
0". Why don't we use a boolean then OR why isn't the third state in
get_const_expr() applicable here?
6. "will" or "should" is missing from the following sentence.
"Plain var nodes either be same as some GROUP BY expression or part of some
GROUP BY expression.
7. The changes in block
else
{
/*
* If we have sortgroupref set, then it means that we have an
* ORDER BY entry pointing to this expression. Since we are
* not pushing ORDER BY with GROUP BY, clear it.
*/
if (sgref)
grouping_target->sortgrouprefs[i] = 0;
/* Not matched exactly, pull the var with aggregates then */
aggvars = pull_var_clause((Node *) expr,
PVC_INCLUDE_AGGREGATES);
if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars))
return false;
/*
* Add aggregates, if any, into the targetlist. Plain var
* nodes either be same as some GROUP BY expression or part of
* some GROUP BY expression. In later case, the query cannot
* refer plain var nodes without the surrounding expression.
* In both the cases, they are already part of the targetlist
* and thus no need to add them again. In fact adding pulled
* plain var nodes in SELECT clause will cause an error on the
* foreign server if they are not same as some GROUP BY
* expression.
*/
foreach(l, aggvars)
{
Expr *expr = (Expr *) lfirst(l);
if (IsA(expr, Aggref))
tlist = add_to_flat_tlist(tlist, list_make1(expr));
}
}
and those in the block
if (fpinfo->local_conds)
{
ListCell *lc;
List *aggvars = pull_var_clause((Node *) fpinfo->local_conds,
PVC_INCLUDE_AGGREGATES);
foreach(lc, aggvars)
{
Expr *expr = (Expr *) lfirst(lc);
/*
* If aggregates within local conditions are not safe to push down,
* then we cannot push down the query. Vars are already part of
* GROUP BY clause which are checked above, so no need to access
* them again here.
*/
if (IsA(expr, Aggref) && !is_foreign_expr(root, grouped_rel, expr))
return false;
}
/* Add Vars and aggregates into the target list. */
tlist = add_to_flat_tlist(tlist, aggvars);
}
should be in sync. The later block adds both aggregates and Vars but the first
one doesn't. Why is this difference?
8. In the comment, "If input rel is not safe to pushdown, then simply return
as we cannot perform any post-join operations remotely on it.", "remotely on
it" may be rephrased as "on the foreign server." to be consistent with the
terminology at in the file.
9. EXPLAIN of foreign scan is adding paranthesis around output expressions,
which is not needed. EXPLAIN output of other plan nodes like Aggregate doesn't
do that. If it's easy to avoid paranthesis, we should do it in this patch. With
this patch, we have started pushing down expressions in the target list, so
makes sense to fix it in this patch.
10. While deparsing the GROUP BY clauses, the code fetches the expressions and
deparses the expressions. We might save some CPU cycles if we deparse the
clauses by their positional indexes in SELECT clause instead of the actual
expressions. This might make the query slightly unreadable. What do you think?
Comments about tests:
1. I don't think the comment below is required. Someone wants to know the
status of that flag might read the corresponding CREATE TABLE command.
+-- Both ft1 and ft2 are used to exercise cost estimates when
+-- use_remote_estimate is false and true respectively.
2. I am assuming that you will remove the SQL statements involving local
tables. They are being used only to test the outputs.
3. The test select count(c6) from ft1; may be clubbed with a previous
testcase? Why is it separate? Some tests like this do not have comments
explaining the purpose behind them. Can you please add comments there.
4. May be bulk of these testcases need to be moved next to Join testcases.
That way their outputs do not change in case the DMLs change in future. In case
you do that, adjust capitalization accordingly.
5. Can we merge following testcase
+select count(*) from ft1 t1 inner join ft2 t2 on (t1.c2 = t2.c2)
where t2.c2 = 6;
with a testcase just before that? I don't see much point in having them
separate.
6. From the comments below, it seems that you want to test the case when the
underlying scan (as a whole) has some local conditions. But the way case has
been written, the underlying join is itself not pushable. Is this intended?
+-- Not pushed down due to local conditions present in underneath input relk
+explain (verbose, costs off)
+select count(*) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2 * random());
7. Instead of separating tests with and without GROUP BY clause into separate
sections, you may want to add them one after the other. Better even if you can
combine them to reduce the number of SQL statements in the file. Do you see any
advantage in having them separate?
8. These two testcases are commented
+--select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+--select "C 1" * random(), sum("C 1") * "C 1" from "S 1"."T 1" group by "C 1";
Either uncomment them and add expected output or remove them altogether. I do
not see any purpose in having them commented.
9. The comment below is too specific.
+-- Aggregate is not pushed down as random() is part of group by expression
It should probably be "Aggregates with unshippable GROUP BY clause are not
shippable" or something general like that.
10. Need some comment about the intention of this and following 3 tests.
+explain (verbose, costs off)
+select count(c2), 5 from ft1 group by 2;
11. About section C, I have a comment similar to comment 7 above. I see that
you have built testcases by gradually adding each clause to a simple SQL
statement. It will become more evident if the improvizations next to the simple
test. Again better if we can merge them into one. Maintaining expected output
of many testcases becomes a pain, if the plans change in future.
12. Following comments
+-- Having clause with random() will be evaluated locally
+-- Having clause with random() will be evaluated locally, and other
having qual is pushed
may be better worded as "Unshippable having clause will be evaluated locally."
to clarify the intention behind the testcase.
13. Wouldn't having random() in the testcase, make them produce different
output in different runs? Also, please see if we can reduce the output rows to
a handful few. Following query produces 21 rows. Is it really important to have
all those rows in the output?
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() <
500000 order by c2;
14. For many testcases in section D, one needs to read the testcases carefully
in order to understand the difference between successive testcases. A comment
line clarifying the intention will help.
15. If you have GROUP BY expression in the SELECT clause and apply DISTINCT on
it, DISTINCT is not going to have any effect, will it?
+select distinct sum(c1), c2 from ft2 where c2 < 6 group by c2 order by c2;
16. In the following query, the subquery returns only a single row, so DISTINCT
doesn't have any effects. Please change the subquery to return multiple rows
with some duplicates so that DISTINCT will be propertly tested.
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 <
10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
What's the difference between this query and the next one. The comment mentions
INNER and OUTER queries, but I don't see that difference. Am I missing
something?
17. Please mention Why.
+-- Aggregate not pushed down
18. Please club percentile and rank testcases into one to reduce number of SQL
statements.
19. This comment is misleading. VARIADIC is not the reason why the aggregate
was not being pushed down.
+-- Now aggregate with VARIADIC will be pushed
20. Why do we need the last statement ALTERing server extensions? Is it not
already done when the function was added to the extension?
+alter extension postgres_fdw drop function least_accum(anyelement,
variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
21. Following comment is misleading. It will not be pushed down because a user
defined operator is considered unshippable (unless it's part of an extension
known to be shippable.)
+-- This will not be pushed as sort operator is not known to extension.
22. Is following scenario already covered in testcases in section for HAVING?
+-- Clauses with random() will be evaluated locally, and other clauses
are pushed
23. This comment talks about deeper code level internal details. Should have a
better user-visible explanations.
+-- ORDER BY expression is not present as is in target list of remote
query. This needed clearing out sortgrouprefs flag.
24. In the following query, which tests PlaceHolderVars, shouldn't there be an
aggregate on the placeholder column i.e. q.a? Else, I don't see much use of
this case in the context of aggregates. Also, for some reason, the planner
thinks that only avg(ft1.c1) is useful and other two can be nullified. Is that
intentional?
+select count(ft4.c1), sum(q.b) from ft4 left join (select 13,
avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)
where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between
10 and 15 group by q.b order by 1;
25. Following test looks more appropriate as a join pushdown test, rather than
aggregate pushdown. Nothing in this test gets pushed down.
+select q.a, count(q.a), avg(ft2.c1) from (select 13 from ft1 where c1
= 13) q(a) right join ft2 on (q.a = ft2.c1) where ft2.c1 between 10
and 15 group by q.a order by 1 nulls last;
26. Instead of the testcase below a test which has window aggregates over a
pushed down aggregate makes sense in the context of aggregate pushdown.
+-- WindowAgg
+explain (verbose, costs off)
+select c2, count(c2) over (partition by c2%2) from ft2 where c2 < 10
order by 1 limit 5 offset 95;
postgres_fdw.out has grown by 2000 lines because of testcases in this
patch. We need to compact the testcases so that easier to maintain in
the future.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
This patch will need some changes to conversion_error_callback(). That
function reports an error in case there was an error converting the
result obtained from the foreign server into an internal datum e.g.
when the string returned by the foreign server is not acceptable by
local input function for the expected datatype. In such cases, the
input function will throw error and conversion_error_callback() will
provide appropriate context for that error. postgres_fdw.sql has tests
to test proper context
-- ===================================================================
-- conversion error
-- ===================================================================
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
SELECT * FROM ft1 WHERE c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1.c8 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1
AND ft1.c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND
ft1.c1 = 1; -- ERROR
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
Right now we report the column name in the error context. This needs
to change for aggregate pushdown, which is pushing down expressions.
Right now, in case the aggregate on foreign server produces a string
unacceptable locally, it would crash at
4982 Assert(IsA(var, Var));
4983
4984 rte = rt_fetch(var->varno, estate->es_range_table);
since it's not a Var node as expected.
We need to fix the error context to provide meaningful information or
at least not crash. This has been discussed briefly in [1]/messages/by-id/CAFjFpRdcC7Ykb1SkARBYikx9ubKniBiAgHqMD9e47TxzY2EYFw@mail.gmail.com.
[1]: /messages/by-id/CAFjFpRdcC7Ykb1SkARBYikx9ubKniBiAgHqMD9e47TxzY2EYFw@mail.gmail.com
On Fri, Sep 16, 2016 at 7:15 PM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
Hi,
On Mon, Sep 12, 2016 at 5:17 PM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:Thanks Ashutosh for the detailed review comments.
I am working on it and will post updated patch once I fix all your
concerns.Attached new patch fixing the review comments.
Here are few comments on the review points:
1. Renamed deparseFromClause() to deparseFromExpr() and
deparseAggOrderBy() to appendAggOrderBy()2. Done
3. classifyConditions() assumes list expressions of type RestrictInfo. But
HAVING clause expressions (and JOIN conditions) are plain expressions. Do
you mean we should modify the classifyConditions()? If yes, then I think it
should be done as a separate (cleanup) patch.4, 5. Both done.
6. Per my understanding, I think checking for just aggregate function is
enough as we are interested in whole aggregate result. Meanwhile I will
check whether we need to find and check shippability of transition,
combination and finalization functions or not.7, 8, 9, 10, 11, 12. All done.
13. Fixed. However instead of adding new function made those changes inline.
Adding support for deparsing List expressions separating list by comma can
be
considered as cleanup patch as it will touch other code area not specific to
aggregate push down.14, 15, 16, 17. All done.
18. I think re-factoring estimate_path_cost_size() should be done separately
as a cleanup patch too.19, 20, 21, 22, 23, 24, 25, 26, 27, 28. All done.
29. I have tried passing input rel's relids to fetch_upper_rel() call in
create_grouping_paths(). It solved this patch's issue, but ended up with
few regression failures which is mostly plan changes. I am not sure whether
we get good plan now or not as I have not analyzed them.
So for this patch, I am setting relids in add_foreign_grouping_path()
itself.
However as suggested, used bms_copy(). I still kept the FIXME over there as
I think it should have done by the core itself.30, 31, 32, 33. All done.
Let me know your views.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Hi Ashutosh,
On Mon, Sep 26, 2016 at 2:28 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
Thanks Jeevan for working on the comments.
Ok. Yes, we should also handle bare conditions in
classifyConditions(). I am fine doing it as a separate patch.
Doing that with separate patch would be good.
I don't think add_foreign_grouping_path() is the right place to change
a structure managed by the core and esp when we are half-way adding
paths. An FDW should not meddle with an upper RelOptInfo. Since
create_foreignscan_plan() picks those up from RelOptInfo and both of
those are part of core, we need a place in core to set the
RelOptInfo::relids for an upper relation OR we have stop using
fs_relids for upper relation foreign scans.
Yes, agree that relids must be set by the core rather than a fdw.
However I don't want to touch the core for this patch and also not
exactly sure where we can do that. I think, for this patch, we can
copy relids into grouped_rel in create_grouping_paths() at place
where we assign fdwroutine, userid etc. from the input relation.
Here are some more comments on the patch, mostly focused on the tests.
1. If we dig down each usage of deparse_expr_cxt::scanrel, it boils down
checking whether a given Var comes from given scan relation (deparseVar())
or
checking whether a given Var needs relation qualification while deparsing
(again deparseVar()). I think both of those purposes can be served by
looking
at scanrel::relids, multiple relids implying relation qualification. So,
instead of having a separate member scan_rel, we should instead fetch the
relids from deparse_expr_cxt::foreignrel. I am assuming that the proposed
change to set relids in upper relations is acceptable. If it's not, we
should
pass scanrel->relids through the context instead of scanrel itself.
Yep. Removed scanrel altogether and used relids whenever required.
2. SortGroupClause is a parser node, so we can name
appendSortGroupClause() as
deparseSortGroupClause(), to be consistent with the naming convention. If
we do
that change, may be it's better to pass SortGroupClause as is and handle
other
members of that structure as well.
Renamed appendSortGroupClause() to deparseSortGroupClause().
I have kept this function in sync with get_rule_sortgroupclause() which
takes the Index ref from SortGroupClause(). This function require just
an index and thus passing SortGroupClause as whole is unnecessary. However
we cannot pass entire order by list or group by list, because in case of
order by list we need some extra processing on list elements. So passing
just Index is sufficient and in sync with get_rule_sortgroupclause() too.
4. Following line is correct as long as there is only one upper relation.
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ?
fpinfo->outerrel : rel;
But as we push down more and more of upper operation, there will be a
chain of
upper relations on top of scan relation. So, it's better to assert that the
scanrel is a join or a base relation to be future proof.
After making changes reported in (1), this line has removed.
For future proof, as discussed offline, added Assert() in deparseFromExpr().
5. In deparseConst(), showtype is compared with hardcoded values. The
callers of this function pass hardcoded values. Instead, we should
define an enum and use it. I understand that this logic has been borrowed
from
get_const_expr(), which also uses hardcoded values. Any reason why not to
adopt
a better style here? In fact, it only uses two states for showtype, 0 and
">
0". Why don't we use a boolean then OR why isn't the third state in
get_const_expr() applicable here?
We certainly can add an enum here, but for consistency with other related
code I think using hard-coded value is good for now. Also I see this
comment in prologue of deparseConst()
* This function has to be kept in sync with ruleutils.c's get_const_expr.
So better to have handling like it.
Also, currently we use only two values for showtype. But for consistency
let use int instead of bool. In future if we add support for coercion
expr, then we need this third value. At that time we will not need changes
here.
However if required, we can submit a separate patch for adding enum
instead of int for showtype in ruleutils.c.
7. The changes in block ...
should be in sync. The later block adds both aggregates and Vars but the
first
one doesn't. Why is this difference?
add_to_flat_tlist() is taking care of duplicate entries and thus in second
block, I was calling it after the loop to avoid calling it for every list
element. Well, moved that inside loop like first block.
9. EXPLAIN of foreign scan is adding paranthesis around output expressions,
which is not needed. EXPLAIN output of other plan nodes like Aggregate
doesn't
do that. If it's easy to avoid paranthesis, we should do it in this patch.
With
this patch, we have started pushing down expressions in the target list, so
makes sense to fix it in this patch.
ExecInitForeignScan() while determining scan tuple type from passed
fdw_scan_tlist, has target list containing Vars with varno set to
INDEX_VAR. Due to which while deparsing we go through
resolve_special_varno() and get_special_variable() function which
forces parenthesis around the expression.
I can't think of any easy and quick solution here. So keeping this
as is. Input will be welcome or this can be done separately later.
10. While deparsing the GROUP BY clauses, the code fetches the expressions
and
deparses the expressions. We might save some CPU cycles if we deparse the
clauses by their positional indexes in SELECT clause instead of the actual
expressions. This might make the query slightly unreadable. What do you
think?
To me it is better to have expression in the GROUP BY clause as it is
more readable and easy to understand. Also it is in sync with deparsing
logic in ruleutils.c.
Comments about tests:
4. May be bulk of these testcases need to be moved next to Join testcases.
That way their outputs do not change in case the DMLs change in future. In
case
you do that, adjust capitalization accordingly.
Moved testcases after Join testcases.
However I have not made any capitalization changes. I see many tests
like those elsewhere in the file too. Let me know if that's the policy
to have appropriate capitalization in test-case. I don't want violate
the policy if any and will prefer to do the changes as per the policy.
13. Wouldn't having random() in the testcase, make them produce different
output in different runs? Also, please see if we can reduce the output
rows to
a handful few. Following query produces 21 rows. Is it really important to
have
all those rows in the output?
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() <
500000 order by c2;
The condition is written in such a way that we will get all rows,
nullifying the random() effect, so I don't think there will be any
issue with the multiple runs.
16. In the following query, the subquery returns only a single row, so
DISTINCT
doesn't have any effects. Please change the subquery to return multiple
rows
with some duplicates so that DISTINCT will be propertly tested.
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 <
10) from ft1 t1 where t1.c1 = 6) from ft1 t2 order by 1;
What's the difference between this query and the next one. The comment
mentions
INNER and OUTER queries, but I don't see that difference. Am I missing
something?
In case of INNER aggregate query, we get multiple rows and thus used
DISTINCT to have small number of output. However in case of OUTER
aggregate query, we get single row. But to keep that query much
identical with INNER query, I have used DISTINCT. It becomes easy to
compare and follow too.
Please see the EXPLAIN output for observing difference between INNER
and OUTER aggregate query. When inner query is aggregate query you
should see that aggregation is performing on t1 and when outer query
is aggregate query, you will see t2.
20. Why do we need the last statement ALTERing server extensions? Is it not already done when the function was added to the extension? +alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray); +alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray); +alter server loopback options (set extensions 'postgres_fdw');
Whenever we alter extension, we must refresh the server and thus required
last statement ALTERing server. Without that elements added into extension
does not reflect in the server.
23. This comment talks about deeper code level internal details. Should
have a
better user-visible explanations.
+-- ORDER BY expression is not present as is in target list of remote
query. This needed clearing out sortgrouprefs flag.
Not sure how can I put those comments without referring some code level
internal details. I have tried altering those comments but it will be
good if you too try rephrasing it.
postgres_fdw.out has grown by 2000 lines because of testcases in this
patch. We need to compact the testcases so that easier to maintain in
the future.
I have removed many duplicate tests and also combined many of them.
Also removed tests involving local tables. Testcase changes now
become 1/3 of earlier one.
In the attached patch I have fixed all other review comments you have
posted. All the comments were excellent and helped me a lot to improve
in various areas.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Attachments:
pg_agg_push_down_v3.patchtext/x-patch; charset=US-ASCII; name=pg_agg_push_down_v3.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..d40e91f 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -38,6 +38,7 @@
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/sysattr.h"
+#include "catalog/pg_aggregate.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_namespace.h"
#include "catalog/pg_operator.h"
@@ -47,6 +48,7 @@
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "nodes/plannodes.h"
+#include "nodes/print.h"
#include "optimizer/clauses.h"
#include "optimizer/prep.h"
#include "optimizer/tlist.h"
@@ -55,7 +57,9 @@
#include "utils/builtins.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
+#include "utils/ruleutils.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
/*
@@ -93,7 +97,9 @@ typedef struct foreign_loc_cxt
typedef struct deparse_expr_cxt
{
PlannerInfo *root; /* global planner state */
+
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ RelOptInfo *scanrel; /* the underlying scan relation. */
StringInfo buf; /* output buffer to append to */
List **params_list; /* exprs that will become remote Params */
} deparse_expr_cxt;
@@ -135,7 +141,7 @@ static void deparseColumnRef(StringInfo buf, int varno, int varattno,
static void deparseRelation(StringInfo buf, Relation rel);
static void deparseExpr(Expr *expr, deparse_expr_cxt *context);
static void deparseVar(Var *node, deparse_expr_cxt *context);
-static void deparseConst(Const *node, deparse_expr_cxt *context);
+static void deparseConst(Const *node, deparse_expr_cxt *context, int showtype);
static void deparseParam(Param *node, deparse_expr_cxt *context);
static void deparseArrayRef(ArrayRef *node, deparse_expr_cxt *context);
static void deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context);
@@ -159,6 +165,14 @@ static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context);
static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *joinrel, bool use_alias, List **params_list);
+static void deparseFromExpr(List *quals, deparse_expr_cxt *context);
+static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
+static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
+static void appendAggOrderBy(List *orderList, List *targetList,
+ deparse_expr_cxt *context);
+static void appendFunctionName(Oid funcid, deparse_expr_cxt *context);
+static Node *deparseSortGroupClause(Index ref, List *tlist,
+ deparse_expr_cxt *context);
/*
@@ -631,6 +645,109 @@ foreign_expr_walker(Node *node,
check_type = false;
}
break;
+ case T_Aggref:
+ {
+ Aggref *agg = (Aggref *) node;
+ ListCell *lc;
+
+ /* Not safe to pushdown when not in grouping context */
+ if (glob_cxt->foreignrel->reloptkind != RELOPT_UPPER_REL)
+ return false;
+
+ /* Only non-split aggregates are pushable. */
+ if (agg->aggsplit != AGGSPLIT_SIMPLE)
+ return false;
+
+ /*
+ * If aggregate function used by the expression is not
+ * shippable, it can't be sent to remote because it might
+ * have incompatible semantics on remote side.
+ */
+ if (!is_shippable(agg->aggfnoid, ProcedureRelationId, fpinfo))
+ return false;
+
+ /*
+ * Recurse to input args. aggdirectargs, aggorder and
+ * aggdistinct are all present in args, so no need to
+ * check their shippability explicitly.
+ */
+ foreach(lc, agg->args)
+ {
+ Node *n = (Node *) lfirst(lc);
+
+ /* If TargetEntry, extract the expression from it */
+ if (IsA(n, TargetEntry))
+ {
+ TargetEntry *tle = (TargetEntry *) n;
+ n = (Node *) tle->expr;
+ }
+
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+
+ /*
+ * For aggorder elements, check whether the sort operator, if
+ * specified, is shippable or not.
+ */
+ if (agg->aggorder)
+ {
+ ListCell *lc;
+
+ foreach (lc, agg->aggorder)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+ TargetEntry *tle;
+
+ tle = get_sortgroupref_tle(srt->tleSortGroupRef,
+ agg->args);
+ sortcoltype = exprType((Node *) tle->expr);
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ /* Check shippability of non-default sort operator. */
+ if (srt->sortop != typentry->lt_opr &&
+ srt->sortop != typentry->gt_opr)
+ if (!is_shippable(srt->sortop, OperatorRelationId,
+ fpinfo))
+ return false;
+ }
+ }
+
+ /* Check aggregate filter */
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
+ if (agg->inputcollid == InvalidOid)
+ /* OK, inputs are all noncollatable */ ;
+ else if (inner_cxt.state != FDW_COLLATE_SAFE ||
+ agg->inputcollid != inner_cxt.collation)
+ return false;
+
+ /*
+ * Detect whether node is introducing a collation not derived
+ * from a foreign Var. (If so, we just mark it unsafe for now
+ * rather than immediately returning false, since the parent
+ * node might not care.)
+ */
+ collation = agg->aggcollid;
+ if (collation == InvalidOid)
+ state = FDW_COLLATE_NONE;
+ else if (inner_cxt.state == FDW_COLLATE_SAFE &&
+ collation == inner_cxt.collation)
+ state = FDW_COLLATE_SAFE;
+ else if (collation == DEFAULT_COLLATION_OID)
+ state = FDW_COLLATE_NONE;
+ else
+ state = FDW_COLLATE_UNSAFE;
+ }
+ break;
default:
/*
@@ -720,7 +837,9 @@ deparse_type_name(Oid type_oid, int32 typemod)
* Build the targetlist for given relation to be deparsed as SELECT clause.
*
* The output targetlist contains the columns that need to be fetched from the
- * foreign server for the given relation.
+ * foreign server for the given relation. If foreignrel is an upper relation,
+ * then the output targetlist can also contains expressions to be evaluated on
+ * foreign server.
*/
List *
build_tlist_to_deparse(RelOptInfo *foreignrel)
@@ -729,6 +848,13 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
/*
+ * For upper relation, we have already built the target list while checking
+ * shippability, return that.
+ */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ return fpinfo->grouped_tlist;
+
+ /*
* We require columns specified in foreignrel->reltarget->exprs and those
* required for evaluating the local conditions.
*/
@@ -750,6 +876,7 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
* hence the tlist is ignored for a base relation.
*
* remote_conds is the list of conditions to be deparsed as WHERE clause.
+ * However for upper relation it is deparsed as HAVING clause.
*
* If params_list is not NULL, it receives a list of Params and other-relation
* Vars used in the clauses; these values must be transmitted to the remote
@@ -768,28 +895,49 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *)rel->fdw_private;
+ List *quals;
- /* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
- rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* We handle all relations other than dead one. */
+ Assert(rel->reloptkind != RELOPT_DEADREL);
- /* Fill portions of context common to join and base relation */
+ /* Fill portions of context common to upper, join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
context.params_list = params_list;
- /* Construct SELECT clause and FROM clause */
+ /* Construct SELECT clause */
deparseSelectSql(tlist, retrieved_attrs, &context);
/*
- * Construct WHERE clause
+ * For upper relations, WHERE clause is built from the underneath scan
+ * relation's remote conditions.
*/
- if (remote_conds)
+ if (rel->reloptkind == RELOPT_UPPER_REL)
{
- appendStringInfo(buf, " WHERE ");
- appendConditions(remote_conds, &context);
+ PgFdwRelationInfo *ofpinfo;
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+ quals = ofpinfo->remote_conds;
+ }
+ else
+ quals = remote_conds;
+
+ /* Construct FROM and WHERE clauses */
+ deparseFromExpr(quals, &context);
+
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ {
+ /* Append GROUP BY clause */
+ appendGroupByClause(tlist, &context);
+
+ /* Append HAVING clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " HAVING ");
+ appendConditions(remote_conds, &context);
+ }
}
/* Add ORDER BY clause if we found any useful pathkeys */
@@ -803,7 +951,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
/*
* Construct a simple SELECT statement that retrieves desired columns
* of the specified foreign table, and append it to "buf". The output
- * contains just "SELECT ... FROM ....".
+ * contains just "SELECT ... ".
*
* We also create an integer List of the columns being retrieved, which is
* returned to *retrieved_attrs.
@@ -824,7 +972,8 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -847,14 +996,47 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
+}
- /*
- * Construct FROM clause
- */
+/*
+ * Construct a FROM clause and a WHERE clause, if any, and append those to
+ * "buf".
+ *
+ * quals is the list of clauses to be included in the WHERE clause,
+ * NIL if none.
+ */
+static void
+deparseFromExpr(List *quals, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ PgFdwRelationInfo *fpinfo;
+ RelOptInfo *foreignrel = context->foreignrel;
+ RelOptInfo *scanrel;
+
+ fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
+
+ /* For upper relations, retrieve scanrel from the fpinfo */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ scanrel = fpinfo->outerrel;
+ Assert(scanrel->reloptkind == RELOPT_JOINREL ||
+ scanrel->reloptkind == RELOPT_BASEREL);
+ }
+ else
+ scanrel = foreignrel;
+
+ /* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, context->root, scanrel,
+ (scanrel->reloptkind == RELOPT_JOINREL),
context->params_list);
+
+ /* Construct WHERE clause */
+ if (quals)
+ {
+ appendStringInfo(buf, " WHERE ");
+ appendConditions(quals, context);
+ }
}
/*
@@ -957,7 +1139,7 @@ deparseTargetList(StringInfo buf,
/*
* Deparse the appropriate locking clause (FOR UPDATE or FOR SHARE) for a
- * given relation (context->foreignrel).
+ * given relation (context->scanrel).
*/
static void
deparseLockingClause(deparse_expr_cxt *context)
@@ -1036,7 +1218,7 @@ deparseLockingClause(deparse_expr_cxt *context)
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
- * deparse both WHERE clauses and JOIN .. ON clauses.
+ * deparse WHERE clauses, JOIN .. ON clauses and HAVING clauses.
*/
static void
appendConditions(List *exprs, deparse_expr_cxt *context)
@@ -1126,22 +1308,15 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
foreach(lc, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
- Var *var;
/* Extract expression if TargetEntry node */
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
-
- /* We expect only Var nodes here */
- if (!IsA(var, Var))
- elog(ERROR, "non-Var not expected in target list");
if (i > 0)
appendStringInfoString(buf, ", ");
- deparseVar(var, context);
+ deparseExpr((Expr *) tle->expr, context);
*retrieved_attrs = lappend_int(*retrieved_attrs, i + 1);
-
i++;
}
@@ -1817,7 +1992,7 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
deparseVar((Var *) node, context);
break;
case T_Const:
- deparseConst((Const *) node, context);
+ deparseConst((Const *) node, context, 0);
break;
case T_Param:
deparseParam((Param *) node, context);
@@ -1849,6 +2024,9 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
case T_ArrayExpr:
deparseArrayExpr((ArrayExpr *) node, context);
break;
+ case T_Aggref:
+ deparseAggref((Aggref *)node, context);
+ break;
default:
elog(ERROR, "unsupported expression type for deparse: %d",
(int) nodeTag(node));
@@ -1867,10 +2045,11 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ Relids relids = context->foreignrel->relids;
+ /* Qualify columns when multiple relations are involved. */
+ bool qualify_col = (bms_num_members(relids) > 1) ? true : false;
- if (bms_is_member(node->varno, context->foreignrel->relids) &&
- node->varlevelsup == 0)
+ if (bms_is_member(node->varno, relids) && node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
else
@@ -1910,7 +2089,7 @@ deparseVar(Var *node, deparse_expr_cxt *context)
* This function has to be kept in sync with ruleutils.c's get_const_expr.
*/
static void
-deparseConst(Const *node, deparse_expr_cxt *context)
+deparseConst(Const *node, deparse_expr_cxt *context, int showtype)
{
StringInfo buf = context->buf;
Oid typoutput;
@@ -1922,9 +2101,10 @@ deparseConst(Const *node, deparse_expr_cxt *context)
if (node->constisnull)
{
appendStringInfoString(buf, "NULL");
- appendStringInfo(buf, "::%s",
- deparse_type_name(node->consttype,
- node->consttypmod));
+ if (showtype >= 0)
+ appendStringInfo(buf, "::%s",
+ deparse_type_name(node->consttype,
+ node->consttypmod));
return;
}
@@ -1974,9 +2154,14 @@ deparseConst(Const *node, deparse_expr_cxt *context)
break;
}
+ pfree(extval);
+
+ if (showtype < 0)
+ return;
+
/*
- * Append ::typename unless the constant will be implicitly typed as the
- * right type when it is read in.
+ * For showtype == 0, append ::typename unless the constant will be
+ * implicitly typed as the right type when it is read in.
*
* XXX this code has to be kept in sync with the behavior of the parser,
* especially make_const.
@@ -1995,7 +2180,7 @@ deparseConst(Const *node, deparse_expr_cxt *context)
needlabel = true;
break;
}
- if (needlabel)
+ if (needlabel || showtype > 0)
appendStringInfo(buf, "::%s",
deparse_type_name(node->consttype,
node->consttypmod));
@@ -2092,9 +2277,6 @@ static void
deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
- HeapTuple proctup;
- Form_pg_proc procform;
- const char *proname;
bool use_variadic;
bool first;
ListCell *arg;
@@ -2127,29 +2309,15 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
return;
}
- /*
- * Normal function: display as proname(args).
- */
- proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->funcid));
- if (!HeapTupleIsValid(proctup))
- elog(ERROR, "cache lookup failed for function %u", node->funcid);
- procform = (Form_pg_proc) GETSTRUCT(proctup);
-
/* Check if need to print VARIADIC (cf. ruleutils.c) */
use_variadic = node->funcvariadic;
- /* Print schema name only if it's not pg_catalog */
- if (procform->pronamespace != PG_CATALOG_NAMESPACE)
- {
- const char *schemaname;
-
- schemaname = get_namespace_name(procform->pronamespace);
- appendStringInfo(buf, "%s.", quote_identifier(schemaname));
- }
+ /*
+ * Normal function: display as proname(args).
+ */
+ appendFunctionName(node->funcid, context);
+ appendStringInfoChar(buf, '(');
- /* Deparse the function name ... */
- proname = NameStr(procform->proname);
- appendStringInfo(buf, "%s(", quote_identifier(proname));
/* ... and all the arguments */
first = true;
foreach(arg, node->args)
@@ -2162,8 +2330,6 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
first = false;
}
appendStringInfoChar(buf, ')');
-
- ReleaseSysCache(proctup);
}
/*
@@ -2420,6 +2586,152 @@ deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context)
}
/*
+ * Deparse an Aggref node.
+ */
+static void
+deparseAggref(Aggref *node, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ bool use_variadic;
+
+ /* Only basic, non-split aggregation accepted. */
+ Assert(node->aggsplit == AGGSPLIT_SIMPLE);
+
+ /* Check if need to print VARIADIC (cf. ruleutils.c) */
+ use_variadic = node->aggvariadic;
+
+ /* Find aggregate name from aggfnoid which is a pg_proc entry */
+ appendFunctionName(node->aggfnoid, context);
+ appendStringInfoChar(buf, '(');
+
+ /* Add DISTINCT */
+ appendStringInfo(buf, "%s", (node->aggdistinct != NIL) ? "DISTINCT " : "");
+
+ if (AGGKIND_IS_ORDERED_SET(node->aggkind))
+ {
+ /* Add WITHIN GROUP (ORDER BY ..) */
+ ListCell *arg;
+ bool first = true;
+
+ Assert(!node->aggvariadic);
+ Assert(node->aggorder != NIL);
+
+ foreach(arg, node->aggdirectargs)
+ {
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseExpr((Expr *) lfirst(arg), context);
+ }
+
+ appendStringInfoString(buf, ") WITHIN GROUP (ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ else
+ {
+ /* aggstar can be set only in zero-argument aggregates */
+ if (node->aggstar)
+ appendStringInfoChar(buf, '*');
+ else
+ {
+ ListCell *arg;
+ bool first = true;
+
+ /* ... and all the arguments */
+ foreach(arg, node->args)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(arg);
+ Node *n = (Node *) tle->expr;
+
+ if (tle->resjunk)
+ continue;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ /* Add VARIADIC */
+ if (use_variadic && lnext(arg) == NULL)
+ appendStringInfoString(buf, "VARIADIC ");
+
+ deparseExpr((Expr *) n, context);
+ }
+ }
+
+ /* Add ORDER BY */
+ if (node->aggorder != NIL)
+ {
+ appendStringInfoString(buf, " ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ }
+
+ /* Add FILTER (WHERE ..) */
+ if (node->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ deparseExpr((Expr *) node->aggfilter, context);
+ }
+
+ appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Append ORDER BY within aggregate function.
+ */
+static void
+appendAggOrderBy(List *orderList, List *targetList, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ ListCell *lc;
+ bool first = true;
+
+ foreach (lc, orderList)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Node *sortexpr;
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ sortexpr = deparseSortGroupClause(srt->tleSortGroupRef, targetList,
+ context);
+ sortcoltype = exprType(sortexpr);
+ /* See whether operator is default < or > for datatype */
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ if (srt->sortop == typentry->lt_opr)
+ appendStringInfoString(buf, " ASC");
+ else if (srt->sortop == typentry->gt_opr)
+ appendStringInfoString(buf, " DESC");
+ else
+ {
+ HeapTuple opertup;
+ Form_pg_operator operform;
+
+ appendStringInfoString(buf, " USING ");
+
+ /* Append operator name. */
+ opertup = SearchSysCache1(OPEROID, ObjectIdGetDatum(srt->sortop));
+ if (!HeapTupleIsValid(opertup))
+ elog(ERROR, "cache lookup failed for operator %u", srt->sortop);
+ operform = (Form_pg_operator) GETSTRUCT(opertup);
+ deparseOperatorName(buf, operform);
+ ReleaseSysCache(opertup);
+ }
+
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ else
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+}
+
+/*
* Print the representation of a parameter to be sent to the remote side.
*
* Note: we always label the Param's type explicitly rather than relying on
@@ -2464,6 +2776,41 @@ printRemotePlaceholder(Oid paramtype, int32 paramtypmod,
}
/*
+ * Deparse GROUP BY clause.
+ */
+static void
+appendGroupByClause(List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ Query *query = context->root->parse;
+ ListCell *lc;
+ bool first = true;
+
+ /* Nothing to be done, if there's no GROUP BY clause in the query. */
+ if (!query->groupClause)
+ return;
+
+ appendStringInfo(buf, " GROUP BY ");
+
+ /*
+ * Queries with grouping sets are not pushed down, so we don't grouping
+ * sets here.
+ */
+ Assert(!query->groupingSets);
+
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseSortGroupClause(grp->tleSortGroupRef, tlist, context);
+ }
+}
+
+/*
* Deparse ORDER BY clause according to the given pathkeys for given base
* relation. From given pathkeys expressions belonging entirely to the given
* base relation are obtained and deparsed.
@@ -2505,3 +2852,67 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
}
reset_transmission_modes(nestlevel);
}
+
+/*
+ * appendFunctionName
+ * Deparses function name from given function oid.
+ */
+static void
+appendFunctionName(Oid funcid, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ HeapTuple proctup;
+ Form_pg_proc procform;
+ const char *proname;
+
+ proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
+ if (!HeapTupleIsValid(proctup))
+ elog(ERROR, "cache lookup failed for function %u", funcid);
+ procform = (Form_pg_proc) GETSTRUCT(proctup);
+
+ /* Print schema name only if it's not pg_catalog */
+ if (procform->pronamespace != PG_CATALOG_NAMESPACE)
+ {
+ const char *schemaname;
+
+ schemaname = get_namespace_name(procform->pronamespace);
+ appendStringInfo(buf, "%s.", quote_identifier(schemaname));
+ }
+
+ /* Deparse the function name ... */
+ proname = NameStr(procform->proname);
+ appendStringInfo(buf, "%s", quote_identifier(proname));
+
+ ReleaseSysCache(proctup);
+}
+
+/*
+ * Appends a sort or group clause.
+ *
+ * Like get_rule_sortgroupclause(), returns the expression tree, so caller
+ * need not find it again.
+ */
+static Node *
+deparseSortGroupClause(Index ref, List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ TargetEntry *tle;
+ Expr *expr;
+
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context, 1);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Must force parens for other expressions */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+
+ return (Node *) expr;
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d97e694..b6b3a81 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,14 +861,13 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
---------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
-(5 rows)
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
count
@@ -878,14 +877,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
----------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = c2))
-(5 rows)
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
count
@@ -937,14 +935,13 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
-----------------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
count
@@ -954,14 +951,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
count
@@ -2283,6 +2279,1165 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Sort Key: (count(ft1.c6)), (sum(ft1.c1))
+ -> Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev
+-------+-------+----------------------+-----+------+--------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0
+ 100 | 50000 | 500.0000000000000000 | 5 | 995 | 0
+ 100 | 50100 | 501.0000000000000000 | 6 | 996 | 0
+ 100 | 50200 | 502.0000000000000000 | 7 | 997 | 0
+ 100 | 50300 | 503.0000000000000000 | 8 | 998 | 0
+ 100 | 50400 | 504.0000000000000000 | 9 | 999 | 0
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0
+(10 rows)
+
+-- Only sum() is pushed. Expression will be executed locally.
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+ QUERY PLAN
+------------------------------------------------------
+ Foreign Scan
+ Output: (((sum(c1)))::double precision * random())
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+(4 rows)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------
+ Aggregate
+ Output: sum(((c1)::double precision * random())), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Simple aggregate with WHERE clause
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1" WHERE ((c2 < 5))
+(4 rows)
+
+select sum(c1) from ft2 where c2 < 5;
+ sum
+--------
+ 249500
+(1 row)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where (t1.c1 * t2.c1) * random() < 100;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: ((((t1.c1 * t2.c1))::double precision * random()) < '100'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Sort Key: ((ft1.c2 / 2))
+ -> Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
+(7 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Sort
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Sort Key: ft1.c2, (sum(ft1.c1))
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
+(9 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable function (i.e. random()) out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c1)::double precision * random()), ((sum(c1) * c1)), c1
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * "C 1"), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(4 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+ QUERY PLAN
+--------------------------------------------------------------
+ HashAggregate
+ Output: (((c1)::double precision * random())), c2
+ Group Key: ((ft2.c1)::double precision * random()), ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: ((c1)::double precision * random()), c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+-- GROUP BY clause referencing position in the select list
+explain (verbose, costs off)
+select count(c2), 5 from ft1 group by 2;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5 FROM "S 1"."T 1" GROUP BY 5::integer
+(4 rows)
+
+select count(c2), 5 from ft1 group by 2;
+ count | ?column?
+-------+----------
+ 1000 | 5
+(1 row)
+
+-- Alias used in GROUP BY to reference the expression
+explain (verbose, costs off)
+select count(c2) a, 5.0 b from ft1 group by b;
+ QUERY PLAN
+----------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5.0)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5.0 FROM "S 1"."T 1" GROUP BY 5.0::numeric
+(4 rows)
+
+select count(c2) a, 5.0 b from ft1 group by b;
+ a | b
+------+-----
+ 1000 | 5.0
+(1 row)
+
+-- Constant used in GROUP BY clause
+explain (verbose, costs off)
+select count(c2) from ft1 group by 5::int;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c2)), (5)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), 5 FROM "S 1"."T 1" GROUP BY 5::integer
+(4 rows)
+
+select count(c2) from ft1 group by 5::int;
+ count
+-------
+ 1000
+(1 row)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800))
+(7 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Sort Key: ft1.c5, (count(ft1.c2))
+ -> Foreign Scan
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) = 1.41421356237309515::double precision))
+(7 rows)
+
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Sat Jan 03 00:00:00 1970 | 10
+ Tue Jan 13 00:00:00 1970 | 10
+ Fri Jan 23 00:00:00 1970 | 10
+ Mon Feb 02 00:00:00 1970 | 10
+ Thu Feb 12 00:00:00 1970 | 10
+ Sun Feb 22 00:00:00 1970 | 10
+ Wed Mar 04 00:00:00 1970 | 10
+ Sat Mar 14 00:00:00 1970 | 10
+ Tue Mar 24 00:00:00 1970 | 10
+ Fri Apr 03 00:00:00 1970 | 10
+(10 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
+ Filter: ((((avg(ft1.c1)))::double precision * random()) < '500'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * random()) > 100;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg(((ft1.c1)::double precision * random())) > '100'::double precision)
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(7 rows)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Sort Key: (array_agg(ft1.c1 ORDER BY ft1.c1))
+ -> Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
+(7 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ HashAggregate
+ Output: sum(c1) FILTER (WHERE (((c1)::double precision * random()) < '100'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(6 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY "C 1", c2
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t2
+ Remote SQL: SELECT NULL FROM "S 1"."T 1"
+ -> Materialize
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(11 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
+(20 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- ORDER BY expression is not present as is in the target list of the remote
+-- query. This needed clearing out sortgrouprefs flag in the code. Following
+-- query tests that code path.
+explain (verbose, costs off)
+select (select sum(c2)) from ft1 order by 1;
+ QUERY PLAN
+-----------------------------------------------------
+ Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Result
+ Output: (sum(ft1.c2))
+(10 rows)
+
+select (select sum(c2)) from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Seq Scan on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Filter: (t1.c2 < 10)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(15 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+ 3 | 6
+ 4 | 8
+ 5 | 10
+ 6 | 12
+ 7 | 14
+ 8 | 16
+ 9 | 18
+(9 rows)
+
+reset enable_hashagg;
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: q.b, (count(ft4.c1)), (sum(q.a))
+ Sort Key: q.b, (count(ft4.c1))
+ -> GroupAggregate
+ Output: q.b, count(ft4.c1), sum(q.a)
+ Group Key: q.b
+ -> Sort
+ Output: q.b, ft4.c1, q.a
+ Sort Key: q.b
+ -> Hash Left Join
+ Output: q.b, ft4.c1, q.a
+ Hash Cond: ((ft4.c1)::numeric = q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Hash
+ Output: q.b, q.a
+ -> Subquery Scan on q
+ Output: q.b, q.a
+ -> Foreign Scan
+ Output: (min(13)), (avg(ft1.c1)), (NULL::bigint)
+ Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
+ Remote SQL: SELECT min(13), avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
+(23 rows)
+
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ b | count | sum
+---------------------+-------+-----
+ 12.0000000000000000 | 1 | 13
+ | 2 |
+(2 rows)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> GroupAggregate
+ Output: c2, c6, sum(c1)
+ Group Key: ft1.c2
+ Sort Key: ft1.c6
+ Group Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
-- parameterized queries
-- ===================================================================
-- simple join
@@ -2608,6 +3763,9 @@ CONTEXT: column "c8" of foreign table "ft1"
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
ERROR: invalid input syntax for integer: "foo"
CONTEXT: whole-row reference to foreign table "ft1"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for integer: "foo"
+CONTEXT: processing expression at position 2 in select list
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
-- subtransaction
@@ -4441,12 +5599,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
--------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4485,12 +5643,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
---------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..cdf3f96 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -24,7 +24,9 @@
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "nodes/print.h"
#include "optimizer/cost.h"
+#include "optimizer/clauses.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
@@ -38,6 +40,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/sampling.h"
+#include "utils/selfuncs.h"
PG_MODULE_MAGIC;
@@ -343,6 +346,10 @@ static void postgresGetForeignJoinPaths(PlannerInfo *root,
JoinPathExtraData *extra);
static bool postgresRecheckForeignScan(ForeignScanState *node,
TupleTableSlot *slot);
+static void postgresGetForeignUpperPaths(PlannerInfo *root,
+ UpperRelationKind stage,
+ RelOptInfo *input_rel,
+ RelOptInfo *output_rel);
/*
* Helper functions
@@ -400,12 +407,15 @@ static void conversion_error_callback(void *arg);
static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel,
JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinPathExtraData *extra);
+static bool foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel);
static List *get_useful_pathkeys_for_relation(PlannerInfo *root,
RelOptInfo *rel);
static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel);
static void add_paths_with_pathkeys_for_rel(PlannerInfo *root, RelOptInfo *rel,
Path *epq_path);
-
+static void add_foreign_grouping_paths(PlannerInfo *root,
+ RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel);
/*
* Foreign-data wrapper handler function: return a struct with pointers
@@ -455,6 +465,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
/* Support functions for join push-down */
routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+ /* Support functions for upper relation push-down */
+ routine->GetForeignUpperPaths = postgresGetForeignUpperPaths;
+
PG_RETURN_POINTER(routine);
}
@@ -1120,7 +1133,7 @@ postgresGetForeignPlan(PlannerInfo *root,
* rel->baserestrictinfo + parameterization clauses through
* scan_clauses. For a join rel->baserestrictinfo is NIL and we are
* not considering parameterization right now, so there should be no
- * scan_clauses for a joinrel.
+ * scan_clauses for a joinrel and upper rel either.
*/
Assert(!scan_clauses);
}
@@ -1170,7 +1183,8 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1191,6 +1205,13 @@ postgresGetForeignPlan(PlannerInfo *root,
{
ListCell *lc;
+ /*
+ * Right now, we only consider grouping and aggregation beyond
+ * joins. Queries involving aggregates or grouping do not require
+ * EPQ mechanism, hence should not have an outer plan here.
+ */
+ Assert(foreignrel->reloptkind != RELOPT_UPPER_REL);
+
outer_plan->targetlist = fdw_scan_tlist;
foreach(lc, local_exprs)
@@ -1228,7 +1249,8 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2452,7 +2474,8 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
/*
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
- * either a base relation or a join between foreign relations.
+ * either a base relation or a join between foreign relations or an upper
+ * relation containing foreign relations.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -2505,7 +2528,8 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,25 +2610,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
- {
- /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
- retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
-
- /*
- * Cost as though this were a seqscan, which is pessimistic. We
- * effectively imagine the local_conds are being evaluated
- * remotely, too.
- */
- startup_cost = 0;
- run_cost = 0;
- run_cost += seq_page_cost * foreignrel->pages;
-
- startup_cost += foreignrel->baserestrictcost.startup;
- cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
- run_cost += cpu_per_tuple * foreignrel->tuples;
- }
- else
+ else if (foreignrel->reloptkind == RELOPT_JOINREL)
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
@@ -2670,6 +2676,97 @@ estimate_path_cost_size(PlannerInfo *root,
run_cost += nrows * remote_conds_cost.per_tuple;
run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows;
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+ AggClauseCosts aggcosts;
+ double input_rows;
+ int numGroupCols;
+ double numGroups = 1;
+
+ /*
+ * This cost model is mixture of costing done for sorted and hashed
+ * aggregates in cost_agg(). We are not sure which strategy will
+ * be considered at remote side, thus for simplicity, we put all
+ * startup related costs in startup_cost and all finalization and
+ * run cost are added in total_cost.
+ *
+ * Also, core does not care about costing HAVING expressions and
+ * adding that to the costs. So similarly, here too we are not
+ * considering remote and local conditions for costing.
+ */
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /* Get rows and width from input rel */
+ input_rows = ofpinfo->rows;
+ width = ofpinfo->width;
+
+ /* Collect statistics about aggregates for estimating costs. */
+ MemSet(&aggcosts, 0, sizeof(AggClauseCosts));
+ if (root->parse->hasAggs)
+ {
+ get_agg_clause_costs(root, (Node *) fpinfo->grouped_tlist,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ get_agg_clause_costs(root, (Node *) root->parse->havingQual,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ }
+
+ /* Get number of grouping columns and possible number of groups */
+ numGroupCols = list_length(root->parse->groupClause);
+ numGroups = estimate_num_groups(root,
+ get_sortgrouplist_exprs(root->parse->groupClause,
+ fpinfo->grouped_tlist),
+ input_rows, NULL);
+
+ /*
+ * Number of rows expected from foreign server will be same as that
+ * of number of groups.
+ */
+ rows = retrieved_rows = numGroups;
+
+ /*
+ * Startup cost includes:
+ * 1. Startup cost for underneath input relation
+ * 2. Cost of performing aggregation, per cost_agg()
+ * 3. Startup cost for PathTarget eval
+ */
+ startup_cost = ofpinfo->rel_startup_cost;
+ startup_cost += aggcosts.transCost.startup;
+ startup_cost += aggcosts.transCost.per_tuple * input_rows;
+ startup_cost += (cpu_operator_cost * numGroupCols) * input_rows;
+ startup_cost += ptarget->cost.startup;
+
+ /*
+ * Run time cost includes:
+ * 1. Run time cost of underneath input relation
+ * 2. Run time cost of performing aggregation, per cost_agg()
+ * 4. PathTarget eval cost for each output row
+ */
+ run_cost = ofpinfo->rel_total_cost - ofpinfo->rel_startup_cost;
+ run_cost += aggcosts.finalCost * numGroups;
+ run_cost += cpu_tuple_cost * numGroups;
+ run_cost += ptarget->cost.per_tuple * numGroups;
+ }
+ else
+ {
+ /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
+ retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
+
+ /*
+ * Cost as though this were a seqscan, which is pessimistic. We
+ * effectively imagine the local_conds are being evaluated
+ * remotely, too.
+ */
+ startup_cost = 0;
+ run_cost = 0;
+ run_cost += seq_page_cost * foreignrel->pages;
+
+ startup_cost += foreignrel->baserestrictcost.startup;
+ cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
+ run_cost += cpu_per_tuple * foreignrel->tuples;
+ }
/*
* Without remote estimates, we have no real way to estimate the cost
@@ -4343,6 +4440,333 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
}
/*
+ * Assess whether the aggregation, grouping and having operations can be pushed
+ * down to the foreign server. As a side effect, save information we obtain in
+ * this function to PgFdwRelationInfo of the input relation.
+ */
+static bool
+foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
+{
+ Query *query = root->parse;
+ PathTarget *grouping_target;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) grouped_rel->fdw_private;
+ PgFdwRelationInfo *ofpinfo;
+ List *aggvars;
+ ListCell *lc;
+ int i;
+ List *tlist = NIL;
+
+ /* Grouping Sets are not pushable */
+ if (query->groupingSets)
+ return false;
+
+ /* Get the fpinfo of the underlying scan relation. */
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /*
+ * If underneath input relation has any local conditions, those conditions
+ * are required to be applied before performing aggregation. Hence the
+ * aggregate cannot be pushed down.
+ */
+ if (ofpinfo->local_conds)
+ return false;
+
+ /*
+ * We may need to modify the sortgrouprefs from path target, thus copy it
+ * so that we will not have any undesired effect. We need to modify the
+ * sortgrouprefs when it points to one of the ORDER BY expression but not
+ * to any GROUP BY expression and that expression is not pushed as is. If
+ * we do not clear such entries, then we will end up into an error.
+ */
+ grouping_target = copy_pathtarget(root->upper_targets[UPPERREL_GROUP_AGG]);
+
+ /*
+ * Evaluate grouping targets and check whether they are safe to push down
+ * to the foreign side. All GROUP BY expressions will be part of the
+ * grouping target and thus there is no need to evaluate it separately.
+ * While doing so, add required expressions into target list which
+ * can then be used to pass to foreign server.
+ */
+ i = 0;
+ foreach(lc, grouping_target->exprs)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+ Index sgref = get_pathtarget_sortgroupref(grouping_target, i);
+ ListCell *l;
+
+ /* Check whether this expression is part of GROUP BY clause */
+ if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause))
+ {
+ /*
+ * If any of the GROUP BY expression is not shippable we can not
+ * push down aggregation to the foreign server.
+ */
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* Check entire expression whether it is pushable or not */
+ if (is_foreign_expr(root, grouped_rel, expr))
+ {
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /*
+ * If we have sortgroupref set, then it means that we have an
+ * ORDER BY entry pointing to this expression. Since we are
+ * not pushing ORDER BY with GROUP BY, clear it.
+ */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
+
+ /* Not matched exactly, pull the var with aggregates then */
+ aggvars = pull_var_clause((Node *) expr,
+ PVC_INCLUDE_AGGREGATES);
+
+ if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars))
+ return false;
+
+ /*
+ * Add aggregates, if any, into the targetlist. Plain var
+ * nodes should be either same as some GROUP BY expression or
+ * part of some GROUP BY expression. In later case, the query
+ * cannot refer plain var nodes without the surrounding
+ * expression. In both the cases, they are already part of
+ * the targetlist and thus no need to add them again. In fact
+ * adding pulled plain var nodes in SELECT clause will cause
+ * an error on the foreign server if they are not same as some
+ * GROUP BY expression.
+ */
+ foreach(l, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(l);
+
+ if (IsA(expr, Aggref))
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ }
+ }
+
+ i++;
+ }
+
+ /*
+ * Classify the pushable and non-pushable having clauses and save them in
+ * remote_conds and local_conds of grouped_rel::fpinfo.
+ */
+ if (root->hasHavingQual && query->havingQual)
+ {
+ ListCell *lc;
+
+ foreach(lc, (List *) query->havingQual)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
+ else
+ fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
+ }
+ }
+
+ /*
+ * If there are any local conditions, pull Vars and aggregates from it and
+ * check whether they are safe to pushdown or not.
+ */
+ if (fpinfo->local_conds)
+ {
+ ListCell *lc;
+ List *aggvars = pull_var_clause((Node *) fpinfo->local_conds,
+ PVC_INCLUDE_AGGREGATES);
+
+ foreach(lc, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ /*
+ * If aggregates within local conditions are not safe to push down,
+ * then we cannot push down the query. Vars are already part of
+ * GROUP BY clause which are checked above, so no need to access
+ * them again here.
+ */
+ if (IsA(expr, Aggref))
+ {
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ tlist = add_to_flat_tlist(tlist, aggvars);
+ }
+ }
+ }
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, grouping_target);
+ /* Store generated targetlist */
+ fpinfo->grouped_tlist = tlist;
+
+ /* Safe to pushdown */
+ fpinfo->pushdown_safe = true;
+
+ /*
+ * If user is willing to estimate cost for a scan using EXPLAIN, he intends
+ * to estimate scans on that relation more accurately. Then, it makes sense
+ * to estimate the cost of the grouping on that relation more accurately
+ * using EXPLAIN.
+ */
+ fpinfo->use_remote_estimate = ofpinfo->use_remote_estimate;
+
+ /* Copy startup and tuple cost as is from underneath input rel's fpinfo */
+ fpinfo->fdw_startup_cost = ofpinfo->fdw_startup_cost;
+ fpinfo->fdw_tuple_cost = ofpinfo->fdw_tuple_cost;
+
+ /*
+ * Set cached relation costs to some negative value, so that we can detect
+ * when they are set to some sensible costs, during one (usually the
+ * first) of the calls to estimate_path_cost_size().
+ */
+ fpinfo->rel_startup_cost = -1;
+ fpinfo->rel_total_cost = -1;
+
+ /* Set fetch size same as that of underneath input rel's fpinfo */
+ fpinfo->fetch_size = ofpinfo->fetch_size;
+
+ /*
+ * Set the string describing this grouped relation to be used in EXPLAIN
+ * output of corresponding ForeignScan.
+ */
+ fpinfo->relation_name = makeStringInfo();
+ appendStringInfo(fpinfo->relation_name, "Aggregate on (%s)",
+ ofpinfo->relation_name->data);
+
+ return true;
+}
+
+/*
+ * postgresGetForeignUpperPaths
+ * Add paths for post-join operations like aggregation, grouping etc. if
+ * corresponding operations are safe to push down.
+ *
+ * Right now, we only support aggregate, grouping and having clause pushdown.
+ */
+static void
+postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
+ RelOptInfo *input_rel, RelOptInfo *output_rel)
+{
+ PgFdwRelationInfo *fpinfo;
+
+ /*
+ * If input rel is not safe to pushdown, then simply return as we cannot
+ * perform any post-join operations on the foreign server.
+ */
+ if (!input_rel->fdw_private ||
+ !((PgFdwRelationInfo *) input_rel->fdw_private)->pushdown_safe)
+ return;
+
+ /*
+ * This should not happen normally. In case we have already added paths for
+ * this output rel, nothing to be done again.
+ */
+ if (output_rel->fdw_private)
+ return;
+
+ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+ fpinfo->pushdown_safe = false;
+ output_rel->fdw_private = fpinfo;
+
+ if (stage == UPPERREL_GROUP_AGG)
+ return add_foreign_grouping_paths(root, input_rel, output_rel);
+
+ /* If it's anything else, we are not adding any foreign path. */
+ return;
+}
+
+/*
+ * add_foreign_grouping_paths
+ * Add foreign path for grouping and/or aggregation.
+ *
+ * Given input_rel represents the underlying scan. The paths are added to the
+ * given grouped_rel.
+ */
+static void
+add_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel)
+{
+ Query *parse = root->parse;
+ PgFdwRelationInfo *ifpinfo = input_rel->fdw_private;
+ PgFdwRelationInfo *fpinfo = grouped_rel->fdw_private;
+ ForeignPath *grouppath;
+ PathTarget *grouping_target;
+ double rows;
+ int width;
+ Cost startup_cost;
+ Cost total_cost;
+
+ /* Nothing to be done, if there is no grouping or aggregation required. */
+ if (!parse->groupClause && !parse->groupingSets && !parse->hasAggs &&
+ !root->hasHavingQual)
+ return;
+
+ grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /*
+ * We need relids to deparse column references from target list.
+ * FIXME: Is this a correct place to copy relids from underneath input_rel
+ * to the grouped_rel for which we are adding a path here? Or this should
+ * have been already set by core itself?
+ */
+ grouped_rel->relids = bms_copy(input_rel->relids);
+
+ /* save the input_rel as outerrel in fpinfo */
+ fpinfo->outerrel = input_rel;
+
+ /*
+ * Copy foreign table, foreign server, user mapping, shippable extensions
+ * etc. details from underneath input relation's fpinfo.
+ */
+ fpinfo->table = ifpinfo->table;
+ fpinfo->server = ifpinfo->server;
+ fpinfo->user = ifpinfo->user;
+ fpinfo->shippable_extensions = ifpinfo->shippable_extensions;
+
+ /* Assess if it is safe to push down aggregation and grouping. */
+ if (!foreign_grouping_ok(root, grouped_rel))
+ return;
+
+ /* Estimate the cost of push down */
+ estimate_path_cost_size(root, grouped_rel, NIL, NIL, &rows,
+ &width, &startup_cost, &total_cost);
+
+ /* Now update this information in the fpinfo */
+ fpinfo->rows = rows;
+ fpinfo->width = width;
+ fpinfo->startup_cost = startup_cost;
+ fpinfo->total_cost = total_cost;
+
+ /* Create and add foreign path to the grouping relation. */
+ grouppath = create_foreignscan_path(root,
+ grouped_rel,
+ grouping_target,
+ rows,
+ startup_cost,
+ total_cost,
+ NIL, /* no pathkeys */
+ NULL, /* no required_outer */
+ NULL,
+ NULL); /* no fdw_private */
+
+ /* Add generated path into grouped_rel by add_path(). */
+ add_path(grouped_rel, (Path *) grouppath);
+
+ return;
+}
+
+/*
* Create a tuple from the specified row of the PGresult.
*
* rel is the local representation of the foreign table, attinmeta is
@@ -4549,24 +4973,34 @@ conversion_error_callback(void *arg)
ForeignScan *fsplan = (ForeignScan *) fsstate->ss.ps.plan;
EState *estate = fsstate->ss.ps.state;
TargetEntry *tle;
- Var *var;
- RangeTblEntry *rte;
Assert(IsA(fsplan, ForeignScan));
tle = (TargetEntry *) list_nth(fsplan->fdw_scan_tlist,
errpos->cur_attno - 1);
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
- Assert(IsA(var, Var));
- rte = rt_fetch(var->varno, estate->es_range_table);
+ /*
+ * Target list can have Vars and expressions. For Vars, we can get
+ * it's relation, however for expressions we can't. Thus for
+ * expressions, just show generic context message.
+ */
+ if (IsA(tle->expr, Var))
+ {
+ RangeTblEntry *rte;
+ Var *var = (Var *) tle->expr;
- if (var->varattno == 0)
- is_wholerow = true;
- else
- attname = get_relid_attribute_name(rte->relid, var->varattno);
+ rte = rt_fetch(var->varno, estate->es_range_table);
+
+ if (var->varattno == 0)
+ is_wholerow = true;
+ else
+ attname = get_relid_attribute_name(rte->relid, var->varattno);
- relname = get_rel_name(rte->relid);
+ relname = get_rel_name(rte->relid);
+ }
+ else
+ errcontext("processing expression at position %d in select list",
+ errpos->cur_attno);
}
if (relname)
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 67126bc..f8c255e 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -92,6 +92,9 @@ typedef struct PgFdwRelationInfo
RelOptInfo *innerrel;
JoinType jointype;
List *joinclauses;
+
+ /* Grouping information */
+ List *grouped_tlist;
} PgFdwRelationInfo;
/* in postgres_fdw.c */
@@ -155,7 +158,7 @@ extern void deparseAnalyzeSql(StringInfo buf, Relation rel,
List **retrieved_attrs);
extern void deparseStringLiteral(StringInfo buf, const char *val);
extern Expr *find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel);
-extern List *build_tlist_to_deparse(RelOptInfo *foreign_rel);
+extern List *build_tlist_to_deparse(RelOptInfo *foreignrel);
extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, List *tlist,
List *remote_conds, List *pathkeys,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f68e89..c7487b4 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -541,6 +541,329 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
+
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1 group by c2 order by 1, 2;
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from ft1 group by c2 order by 1, 2;
+
+-- Only sum() is pushed. Expression will be executed locally.
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * random()), avg(c1) from ft1;
+
+-- Simple aggregate with WHERE clause
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+select sum(c1) from ft2 where c2 < 5;
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where (t1.c1 * t2.c1) * random() < 100;
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+
+-- Aggregate is still pushed down by taking unshippable function (i.e. random()) out
+explain (verbose, costs off)
+select c1 * random(), sum(c1) * c1 from ft1 group by c1;
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c1 * random() from ft2 group by c1 * random(), c2;
+
+-- GROUP BY clause referencing position in the select list
+explain (verbose, costs off)
+select count(c2), 5 from ft1 group by 2;
+select count(c2), 5 from ft1 group by 2;
+
+-- Alias used in GROUP BY to reference the expression
+explain (verbose, costs off)
+select count(c2) a, 5.0 b from ft1 group by b;
+select count(c2) a, 5.0 b from ft1 group by b;
+
+-- Constant used in GROUP BY clause
+explain (verbose, costs off)
+select count(c2) from ft1 group by 5::int;
+select count(c2) from ft1 group by 5::int;
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having avg(c1) * random() < 500 and avg(c1) < 500) x;
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * random()) > 100;
+
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where c1 * random() < 100) from ft1 group by c2;
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+
+
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+
+create operator family my_op_family using btree;
+
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null;
+
+-- ORDER BY expression is not present as is in the target list of the remote
+-- query. This needed clearing out sortgrouprefs flag in the code. Following
+-- query tests that code path.
+explain (verbose, costs off)
+select (select sum(c2)) from ft1 order by 1;
+select (select sum(c2)) from ft1 order by 1;
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+reset enable_hashagg;
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+
+
-- ===================================================================
-- parameterized queries
-- ===================================================================
@@ -624,6 +947,7 @@ ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
SELECT * FROM ft1 WHERE c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1.c8 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
On Mon, Sep 26, 2016 at 6:15 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
This patch will need some changes to conversion_error_callback(). That
function reports an error in case there was an error converting the
result obtained from the foreign server into an internal datum e.g.
when the string returned by the foreign server is not acceptable by
local input function for the expected datatype. In such cases, the
input function will throw error and conversion_error_callback() will
provide appropriate context for that error. postgres_fdw.sql has tests
to test proper context
We need to fix the error context to provide meaningful information or
at least not crash. This has been discussed briefly in [1].
Oops. I had that in mind when working on this. Somehow skipped checking
for conversion error context. I have fixed that in v3 patch.
Removed assert and for non Var expressions, printing generic context.
This context is almost in-line with the discussion you referred here.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Fri, Sep 30, 2016 at 8:58 PM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
On Mon, Sep 26, 2016 at 6:15 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:This patch will need some changes to conversion_error_callback(). That
function reports an error in case there was an error converting the
result obtained from the foreign server into an internal datum e.g.
when the string returned by the foreign server is not acceptable by
local input function for the expected datatype. In such cases, the
input function will throw error and conversion_error_callback() will
provide appropriate context for that error. postgres_fdw.sql has tests
to test proper context
We need to fix the error context to provide meaningful information or
at least not crash. This has been discussed briefly in [1].Oops. I had that in mind when working on this. Somehow skipped checking
for conversion error context. I have fixed that in v3 patch.
Removed assert and for non Var expressions, printing generic context.
This context is almost in-line with the discussion you referred here.
Moved to next CF.
--
Michael
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Thanks Jeevan for taking care of the comments.
On Fri, Sep 30, 2016 at 5:23 PM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
Hi Ashutosh,
On Mon, Sep 26, 2016 at 2:28 PM, Ashutosh Bapat
<ashutosh.bapat@enterprisedb.com> wrote:Thanks Jeevan for working on the comments.
Ok. Yes, we should also handle bare conditions in
classifyConditions(). I am fine doing it as a separate patch.Doing that with separate patch would be good.
Ok.
I don't think add_foreign_grouping_path() is the right place to change
a structure managed by the core and esp when we are half-way adding
paths. An FDW should not meddle with an upper RelOptInfo. Since
create_foreignscan_plan() picks those up from RelOptInfo and both of
those are part of core, we need a place in core to set the
RelOptInfo::relids for an upper relation OR we have stop using
fs_relids for upper relation foreign scans.Yes, agree that relids must be set by the core rather than a fdw.
However I don't want to touch the core for this patch and also not
exactly sure where we can do that. I think, for this patch, we can
copy relids into grouped_rel in create_grouping_paths() at place
where we assign fdwroutine, userid etc. from the input relation.
I don't think this is acceptable since it changes the search key for
an upper without going through fetch_upper_rel(). Rest of the code,
which tries to find this upper rel with relids = NULL, will not be
able to find it anymore. I have started a discussion on this topic
[1]: http://www.mail-archive.com/pgsql-hackers@postgresql.org/msg295435.html -- Best Wishes, Ashutosh Bapat EnterpriseDB Corporation The Postgres Database Company
an upper rel. But that solution looks temporary. The discussion has
not yet concluded.
In case we decide not to have any relids in the upper relation, we
will have to obtain those from the scanrel in the context, which is
not being used right now.
Also there are places in code where we check reloptkind and assume it
to be either JOINREL or BASEREL e.g. deparseLockingClause. Those need
to be examined again since now we handle an upper relation. As
discussed before, we might user bms_num_members() on relids to decide
whether the underlying scan is join or base relation.
2. SortGroupClause is a parser node, so we can name
appendSortGroupClause() as
deparseSortGroupClause(), to be consistent with the naming convention. If
we do
that change, may be it's better to pass SortGroupClause as is and handle
other
members of that structure as well.Renamed appendSortGroupClause() to deparseSortGroupClause().
I have kept this function in sync with get_rule_sortgroupclause() which
takes the Index ref from SortGroupClause(). This function require just
an index and thus passing SortGroupClause as whole is unnecessary. However
we cannot pass entire order by list or group by list, because in case of
order by list we need some extra processing on list elements. So passing
just Index is sufficient and in sync with get_rule_sortgroupclause() too.
Ok.
In this function
+ /* Must force parens for other expressions */
Please explain why we need parenthesis.
5. In deparseConst(), showtype is compared with hardcoded values. The
callers of this function pass hardcoded values. Instead, we should
define an enum and use it. I understand that this logic has been borrowed
from
get_const_expr(), which also uses hardcoded values. Any reason why not to
adopt
a better style here? In fact, it only uses two states for showtype, 0 and
">
0". Why don't we use a boolean then OR why isn't the third state in
get_const_expr() applicable here?We certainly can add an enum here, but for consistency with other related
code I think using hard-coded value is good for now. Also I see this
comment in prologue of deparseConst()
* This function has to be kept in sync with ruleutils.c's get_const_expr.So better to have handling like it.
Also, currently we use only two values for showtype. But for consistency
let use int instead of bool. In future if we add support for coercion
expr, then we need this third value. At that time we will not need changes
here.
However if required, we can submit a separate patch for adding enum
instead of int for showtype in ruleutils.c.
Since this patch adds showtype argument which is present in
get_const_expr(), it's clear that we haven't really kept those two
functions in sync, even though the comment says so. It's kind of ugly
to see those hardcoded values. But you have a point. Let's see what
committer says.
7. The changes in block ...
should be in sync. The later block adds both aggregates and Vars but the
first
one doesn't. Why is this difference?add_to_flat_tlist() is taking care of duplicate entries and thus in second
block, I was calling it after the loop to avoid calling it for every list
element. Well, moved that inside loop like first block.
+ /*
+ * We may need to modify the sortgrouprefs from path target, thus copy it
+ * so that we will not have any undesired effect. We need to modify the
+ * sortgrouprefs when it points to one of the ORDER BY expression but not
+ * to any GROUP BY expression and that expression is not pushed as is. If
+ * we do not clear such entries, then we will end up into an error.
+ */
What kind of error? Explain it better.
9. EXPLAIN of foreign scan is adding paranthesis around output
expressions,
which is not needed. EXPLAIN output of other plan nodes like Aggregate
doesn't
do that. If it's easy to avoid paranthesis, we should do it in this patch.
With
this patch, we have started pushing down expressions in the target list,
so
makes sense to fix it in this patch.ExecInitForeignScan() while determining scan tuple type from passed
fdw_scan_tlist, has target list containing Vars with varno set to
INDEX_VAR. Due to which while deparsing we go through
resolve_special_varno() and get_special_variable() function which
forces parenthesis around the expression.
I can't think of any easy and quick solution here. So keeping this
as is. Input will be welcome or this can be done separately later.
I guess, you can decide whether or not to add paranthesis by looking
at the corresponding namespace in the deparse_context. If the
planstate there is ForeignScanState, you may skip the paranthesis if
istoplevel is true. Can you please check if this works?
10. While deparsing the GROUP BY clauses, the code fetches the expressions
and
deparses the expressions. We might save some CPU cycles if we deparse the
clauses by their positional indexes in SELECT clause instead of the actual
expressions. This might make the query slightly unreadable. What do you
think?To me it is better to have expression in the GROUP BY clause as it is
more readable and easy to understand. Also it is in sync with deparsing
logic in ruleutils.c.
Not exactly. get_rule_sortgroupclause() prints only the target list
positions instead of actual expression in GROUP BY or ORDER BY clause
if requested so. We could opt to do the same in all cases. But I think
it's better to add the whole expression in the remote query for
readability.
Comments about tests:
4. May be bulk of these testcases need to be moved next to Join testcases.
That way their outputs do not change in case the DMLs change in future. In
case
you do that, adjust capitalization accordingly.Moved testcases after Join testcases.
However I have not made any capitalization changes. I see many tests
like those elsewhere in the file too. Let me know if that's the policy
to have appropriate capitalization in test-case. I don't want violate
the policy if any and will prefer to do the changes as per the policy.
This file has used different styles for different sets. But we usually
adopt the style from surrounding testcases. The testcases surrounding
aggregate testcase block are capitalized. It will look odd to have
just the aggregate tests using different style.
13. Wouldn't having random() in the testcase, make them produce different
output in different runs? Also, please see if we can reduce the output
rows to
a handful few. Following query produces 21 rows. Is it really important to
have
all those rows in the output?
+select c2, sum(c1) from ft2 group by c2 having sum(c1) * random() <
500000 order by c2;The condition is written in such a way that we will get all rows,
nullifying the random() effect, so I don't think there will be any
issue with the multiple runs.
While I agree with that, we can't deny a future change where the test
returns random results. Usually the other tests have used t1.c8 to
induce an unshippable condition. Or use a condition like (random() <=
1) which is always true for any value returned by random(). The
expression will be deemed as volatile. See if you can do something
like that.
20. Why do we need the last statement ALTERing server extensions? Is it not already done when the function was added to the extension? +alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray); +alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray); +alter server loopback options (set extensions 'postgres_fdw');Whenever we alter extension, we must refresh the server and thus required
last statement ALTERing server. Without that elements added into extension
does not reflect in the server.
Ok.
23. This comment talks about deeper code level internal details. Should
have a
better user-visible explanations.
+-- ORDER BY expression is not present as is in target list of remote
query. This needed clearing out sortgrouprefs flag.Not sure how can I put those comments without referring some code level
internal details. I have tried altering those comments but it will be
good if you too try rephrasing it.
I think that testcase can be simplified if we use a non-shippable
expression where an aggregate if shippable e.g. random() * sum(c2) and
order the result by this expression. Because of the unshippable
expression, ORDER BY won't be pushed down and we test the case when
ORDER BY expression is part of the targetlist but can not be pushed
down. If we do that, this need not be a separate testcase and can be
merged with one of the tests earlier.
I guess, it will suffice if the comment just says that it's testing a
case where ORDER BY expression is part of the targetlist but not
pushed down. You don't need to explain what kind of problem that
showed and how it was fixed. If the code changes later, the comment in
the test will be out of sync.
postgres_fdw.out has grown by 2000 lines because of testcases in this
patch. We need to compact the testcases so that easier to maintain in
the future.I have removed many duplicate tests and also combined many of them.
Also removed tests involving local tables. Testcase changes now
become 1/3 of earlier one.
I guess, there are still avenues for compressing the testcases e.g.
following three testcases and some test cases with HAVING clauses, can
be merged together, since they are testing orthogonal functionality.
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from
ft1 group by c2 order by 1, 2;
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2) from
ft1 group by c2 order by 1, 2;
+
+-- Only sum() is pushed. Expression will be executed locally.
+explain (verbose, costs off)
+select sum(c1) * random() from ft1;
+
+-- Simple aggregate with WHERE clause
+explain (verbose, costs off)
+select sum(c1) from ft2 where c2 < 5;
+select sum(c1) from ft2 where c2 < 5;
Here are some more (mostly minor comments)
Why do we need this deparse.c? Even without this include, the code
compiles fine for me.
+#include "utils/ruleutils.h"
+#include "nodes/print.h"
May be you want to explain when foreignrel and scanrel will be different and
their purpose in the comment just above this structure definition.
Please use "foreign server" instead of "remote".
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
I guess, aggregate's input collation should consider aggfilter collation, since
that doesn't affect aggregates collation. But we should make sure that
aggfilter is safe to pushdown from collation's perspective.
+ /* Check aggregate filter */
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
We need an "a" before upper, I guess.
+ * For upper relation, we have already built the target list while checking
If we add a new kind of RELOPT, this assertion will unintentionally accept it.
May be it's good idea to explicitly list all the RELOPTs even if we support all
of them except one. It was probably I who suggested this change, but thinking
about it again, it doesn't seems to be a good idea. What do you think?
- /* We handle relations for foreign tables and joins between those */
- Assert(rel->reloptkind == RELOPT_JOINREL ||
- rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ /* We handle all relations other than dead one. */
+ Assert(rel->reloptkind != RELOPT_DEADREL);
missing "expect" after ... so we don't
+ /*
+ * Queries with grouping sets are not pushed down, so we don't grouping
+ * sets here.
+ */
Do we need following #include in postgres_fdw.c? I am able to compile the code
fine with those.
+#include "nodes/print.h"
[1]: http://www.mail-archive.com/pgsql-hackers@postgresql.org/msg295435.html -- Best Wishes, Ashutosh Bapat EnterpriseDB Corporation The Postgres Database Company
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Thu, Sep 8, 2016 at 10:41 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
I think we should try to measure performance gain because of aggregate
pushdown. The EXPLAIN
doesn't show actual improvement in the execution times.
I did performance testing for aggregate push down and see good performance
with the patch.
Attached is the script I have used to get the performance numbers along with
the results I got with and without patch (pg_agg_push_down_v3.patch). Also
attached few GNU plots from the readings I got. These were run on my local
VM having following details:
Linux centos7 3.10.0-327.28.3.el7.x86_64 #1 SMP Thu Aug 18 19:05:49 UTC
2016 x86_64 x86_64 x86_64 GNU/Linux
RAM alloted: 8 GB
CPUs alloted: 8
postgresql.conf is default.
With aggregate push down I see around 12x performance for count(*)
operation.
In another test, I have observed that if number of groups returned from
remote server is same as that of input rows, then aggregate push down
performs
slightly poor which I think is expected. However in all other cases where
number of groups are less than input rows, pushing down aggregate gives
better
performance than performing grouping on the local server.
I did this performance testing on my local setup. I would expected even
better
numbers on a specialized high-end performance machine. I would be more than
happy if someone does this testing on such high-end machine.
Let me know if you need any help.
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Fri, Sep 30, 2016 at 5:23 PM, Jeevan Chalke <
jeevan.chalke@enterprisedb.com> wrote:
In the attached patch I have fixed all other review comments you have
posted. All the comments were excellent and helped me a lot to improve
in various areas.
Hi,
I have tested and created few extra testcases which we can consider to add
in "postgres_fdw.sql".
Please find attached patch.
Note: This patch is an addition on top of Jeevan Chalke's patch Dt: 30th,
Sept 2016.
*Thanks & Regards,*
*Prabhat Kumar Sahu*
Mob: 7758988455
Skype ID: prabhat.sahu1984
www.enterprisedb.co <http://www.enterprisedb.com/>m
<http://www.enterprisedb.com/>
Attachments:
pg_agg_push_down_extra_test.patchbinary/octet-stream; name=pg_agg_push_down_extra_test.patchDownload
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index b6b3a81..7682ae2 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -2863,6 +2863,196 @@ select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2
6 | 1
(1 row)
+-- case statement with aggregate functions, Aggregate able to pushdown without CASE.
+EXPLAIN (VERBOSE, COSTS OFF)
+select count(c6), case when count(c6)>50 then 'T' else 'F' end from ft1 group by c2 order by 1,2 limit 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Limit
+ Output: (count(c6)), (CASE WHEN ((count(c6)) > 50) THEN 'T'::text ELSE 'F'::text END), c2
+ -> Sort
+ Output: (count(c6)), (CASE WHEN ((count(c6)) > 50) THEN 'T'::text ELSE 'F'::text END), c2
+ Sort Key: (count(ft1.c6)), (CASE WHEN ((count(ft1.c6)) > 50) THEN 'T'::text ELSE 'F'::text END)
+ -> Foreign Scan
+ Output: (count(c6)), CASE WHEN ((count(c6)) > 50) THEN 'T'::text ELSE 'F'::text END, c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), c2 FROM "S 1"."T 1" GROUP BY c2
+(9 rows)
+
+select count(c6), case when count(c6)>50 then 'T' else 'F' end from ft1 group by c2 order by 1,2 limit 10;
+ count | case
+-------+------
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+ 100 | T
+(10 rows)
+
+-- Aggregate with typecast in immutable function.
+EXPLAIN (VERBOSE, COSTS OFF)
+select date_pl_interval(c5::date, '1 year'), sum(c2) from ft1 group by date_pl_interval(c5::date, '1 year') HAVING sum(c2) = 50 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (date_pl_interval((c5)::date, '@ 1 year'::interval)), (sum(c2))
+ Sort Key: (date_pl_interval((ft1.c5)::date, '@ 1 year'::interval))
+ -> Foreign Scan
+ Output: (date_pl_interval((c5)::date, '@ 1 year'::interval)), (sum(c2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT date_pl_interval(c5::date, '@ 1 year'::interval), sum(c2) FROM "S 1"."T 1" GROUP BY (date_pl_interval(c5::date, '@ 1 year'::interval)) HAVING ((sum(c2) = 50))
+(7 rows)
+
+select date_pl_interval(c5::date, '1 year'), sum(c2) from ft1 group by date_pl_interval(c5::date, '1 year') HAVING sum(c2) = 50 order by 1;
+ date_pl_interval | sum
+--------------------------+-----
+ Wed Jan 06 00:00:00 1971 | 50
+ Sat Jan 16 00:00:00 1971 | 50
+ Tue Jan 26 00:00:00 1971 | 50
+ Fri Feb 05 00:00:00 1971 | 50
+ Mon Feb 15 00:00:00 1971 | 50
+ Thu Feb 25 00:00:00 1971 | 50
+ Sun Mar 07 00:00:00 1971 | 50
+ Wed Mar 17 00:00:00 1971 | 50
+ Sat Mar 27 00:00:00 1971 | 50
+ Tue Apr 06 00:00:00 1971 | 50
+(10 rows)
+
+-- aggregate with foreign table on view created in remote server.
+CREATE VIEW "S 1".t1_vw as select * from "S 1"."T 1";
+CREATE FOREIGN TABLE ft1_vw (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 't1_vw');
+EXPLAIN (VERBOSE, COSTS OFF)
+select count(c2) from ft1_vw group by c2 order by 1 limit 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: (count(c2)), c2
+ -> Sort
+ Output: (count(c2)), c2
+ Sort Key: (count(ft1_vw.c2))
+ -> Foreign Scan
+ Output: (count(c2)), c2
+ Relations: Aggregate on (public.ft1_vw)
+ Remote SQL: SELECT count(c2), c2 FROM "S 1".t1_vw GROUP BY c2
+(9 rows)
+
+select count(c2) from ft1_vw group by c2 order by 1 limit 10;
+ count
+-------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+-- Aggregate with Boolean data every() .
+CREATE TABLE "S 1"."T 7" (
+ c1 int,
+ c2 boolean
+);
+CREATE FOREIGN TABLE ft7 (
+ c1 int,
+ c2 boolean
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 7');
+insert into "S 1"."T 7" (
+ select trunc(random() * 9 + 1),
+ cast(cast(random() as integer) as boolean)
+ from generate_series(1,100)
+);
+EXPLAIN (VERBOSE, COSTS OFF)
+select every(c2) from ft7 group by c1 order by 1;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Output: (every(c2)), c1
+ Sort Key: (every(ft7.c2))
+ -> Foreign Scan
+ Output: (every(c2)), c1
+ Relations: Aggregate on (public.ft7)
+ Remote SQL: SELECT every(c2), c1 FROM "S 1"."T 7" GROUP BY c1
+(7 rows)
+
+select every(c2) from ft7 group by c1 order by 1;
+ every
+-------
+ f
+ f
+ f
+ f
+ f
+ f
+ f
+ f
+ f
+(9 rows)
+
+-- Not pushed down as the join is with base table and foreign server tables.
+EXPLAIN (VERBOSE, COSTS OFF)
+select avg(t1.c1), sum(t4.c1) FROM ft1 t1 JOIN "S 1"."T 4" t4 ON t1.c1 = t4.c1 group by t4.c1 order by 1 limit 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Limit
+ Output: (avg(t1.c1)), (sum(t4.c1)), t4.c1
+ -> Sort
+ Output: (avg(t1.c1)), (sum(t4.c1)), t4.c1
+ Sort Key: (avg(t1.c1))
+ -> GroupAggregate
+ Output: avg(t1.c1), sum(t4.c1), t4.c1
+ Group Key: t4.c1
+ -> Merge Join
+ Output: t4.c1, t1.c1
+ Merge Cond: (t1.c1 = t4.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Sort
+ Output: t4.c1
+ Sort Key: t4.c1
+ -> Seq Scan on "S 1"."T 4" t4
+ Output: t4.c1
+(19 rows)
+
+select avg(t1.c1), sum(t4.c1) FROM ft1 t1 JOIN "S 1"."T 4" t4 ON t1.c1 = t4.c1 group by t4.c1 order by 1 limit 10;
+ avg | sum
+---------------------+-----
+ 3.0000000000000000 | 3
+ 6.0000000000000000 | 6
+ 9.0000000000000000 | 9
+ 12.0000000000000000 | 12
+ 15.0000000000000000 | 15
+ 18.0000000000000000 | 18
+ 21.0000000000000000 | 21
+ 24.0000000000000000 | 24
+ 27.0000000000000000 | 27
+ 30.0000000000000000 | 30
+(10 rows)
+
+-- Cleanup:
+DROP FOREIGN TABLE ft1_vw;
+DROP FOREIGN TABLE ft7;
+DROP VIEW "S 1".t1_vw;
+DROP TABLE "S 1"."T 7";
-- User defined function for user defined aggregate, VARIADIC
create function least_accum(anyelement, variadic anyarray)
returns anyelement language sql as
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c7487b4..7710864 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -687,6 +687,65 @@ explain (verbose, costs off)
select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+-- case statement with aggregate functions, Aggregate able to pushdown without CASE.
+EXPLAIN (VERBOSE, COSTS OFF)
+select count(c6), case when count(c6)>50 then 'T' else 'F' end from ft1 group by c2 order by 1,2 limit 10;
+select count(c6), case when count(c6)>50 then 'T' else 'F' end from ft1 group by c2 order by 1,2 limit 10;
+
+-- Aggregate with typecast in immutable function.
+EXPLAIN (VERBOSE, COSTS OFF)
+select date_pl_interval(c5::date, '1 year'), sum(c2) from ft1 group by date_pl_interval(c5::date, '1 year') HAVING sum(c2) = 50 order by 1;
+select date_pl_interval(c5::date, '1 year'), sum(c2) from ft1 group by date_pl_interval(c5::date, '1 year') HAVING sum(c2) = 50 order by 1;
+
+-- aggregate with foreign table on view created in remote server.
+CREATE VIEW "S 1".t1_vw as select * from "S 1"."T 1";
+CREATE FOREIGN TABLE ft1_vw (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 't1_vw');
+
+EXPLAIN (VERBOSE, COSTS OFF)
+select count(c2) from ft1_vw group by c2 order by 1 limit 10;
+select count(c2) from ft1_vw group by c2 order by 1 limit 10;
+
+-- Aggregate with Boolean data every() .
+CREATE TABLE "S 1"."T 7" (
+ c1 int,
+ c2 boolean
+);
+
+CREATE FOREIGN TABLE ft7 (
+ c1 int,
+ c2 boolean
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 7');
+insert into "S 1"."T 7" (
+ select trunc(random() * 9 + 1),
+ cast(cast(random() as integer) as boolean)
+ from generate_series(1,100)
+);
+
+EXPLAIN (VERBOSE, COSTS OFF)
+select every(c2) from ft7 group by c1 order by 1;
+select every(c2) from ft7 group by c1 order by 1;
+
+-- Not pushed down as the join is with base table and foreign server tables.
+EXPLAIN (VERBOSE, COSTS OFF)
+select avg(t1.c1), sum(t4.c1) FROM ft1 t1 JOIN "S 1"."T 4" t4 ON t1.c1 = t4.c1 group by t4.c1 order by 1 limit 10;
+select avg(t1.c1), sum(t4.c1) FROM ft1 t1 JOIN "S 1"."T 4" t4 ON t1.c1 = t4.c1 group by t4.c1 order by 1 limit 10;
+
+-- Cleanup:
+DROP FOREIGN TABLE ft1_vw;
+DROP FOREIGN TABLE ft7;
+DROP VIEW "S 1".t1_vw;
+DROP TABLE "S 1"."T 7";
+
-- User defined function for user defined aggregate, VARIADIC
create function least_accum(anyelement, variadic anyarray)
returns anyelement language sql as
On Wed, Oct 12, 2016 at 9:18 AM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
I did performance testing for aggregate push down and see good performance
with the patch.
Are you planning another update to this patch based on Ashutosh's comments?
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Wed, Oct 12, 2016 at 3:38 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
I don't think add_foreign_grouping_path() is the right place to change
a structure managed by the core and esp when we are half-way adding
paths. An FDW should not meddle with an upper RelOptInfo. Since
create_foreignscan_plan() picks those up from RelOptInfo and both of
those are part of core, we need a place in core to set the
RelOptInfo::relids for an upper relation OR we have stop using
fs_relids for upper relation foreign scans.Yes, agree that relids must be set by the core rather than a fdw.
However I don't want to touch the core for this patch and also not
exactly sure where we can do that. I think, for this patch, we can
copy relids into grouped_rel in create_grouping_paths() at place
where we assign fdwroutine, userid etc. from the input relation.I don't think this is acceptable since it changes the search key for
an upper without going through fetch_upper_rel(). Rest of the code,
which tries to find this upper rel with relids = NULL, will not be
able to find it anymore. I have started a discussion on this topic
[1]. One possible solution discussed there is to use all_baserels for
an upper rel. But that solution looks temporary. The discussion has
not yet concluded.In case we decide not to have any relids in the upper relation, we
will have to obtain those from the scanrel in the context, which is
not being used right now.Also there are places in code where we check reloptkind and assume it
to be either JOINREL or BASEREL e.g. deparseLockingClause. Those need
to be examined again since now we handle an upper relation. As
discussed before, we might user bms_num_members() on relids to decide
whether the underlying scan is join or base relation.
Done.
Using scan rel's relids in the context and checking for any foreign var
reference. Added Relids member in foreign_glob_cxt and scanrel in
deparse_expr_cxt to accomplish this. Removed logic of copying relids
from scanrel to grouped_rel. In create_foreignscan_plan(), assigned
all_baserels to fs_relids for upper relations per one of the suggestion
mentioned in the said email discussion.
Ok.
In this function
+ /* Must force parens for other expressions */
Please explain why we need parenthesis.
I have observed that in deparse.c we do add parenthesis around
expressions, unlike to PRETTY_PAREN handling in ruleutils.c.
Thus we need parenthesis here too. However changed this comments
per other comment in the file.
Since this patch adds showtype argument which is present in
get_const_expr(), it's clear that we haven't really kept those two
functions in sync, even though the comment says so. It's kind of ugly
to see those hardcoded values. But you have a point. Let's see what
committer says.
Sure, no issues.
ExecInitForeignScan() while determining scan tuple type from passed
fdw_scan_tlist, has target list containing Vars with varno set to
INDEX_VAR. Due to which while deparsing we go through
resolve_special_varno() and get_special_variable() function which
forces parenthesis around the expression.
I can't think of any easy and quick solution here. So keeping this
as is. Input will be welcome or this can be done separately later.I guess, you can decide whether or not to add paranthesis by looking
at the corresponding namespace in the deparse_context. If the
planstate there is ForeignScanState, you may skip the paranthesis if
istoplevel is true. Can you please check if this works?
I have tried it. Attached separate patch for it.
However I have noticed that istoplevel is always false (at-least for the
testcase we have, I get it false always). And I also think that taking
this decision only on PlanState is enough. Does that in attached patch.
To fix this, I have passed deparse_namespace to the private argument and
accessed it in get_special_variable(). Changes looks very simple. Please
have a look and let me know your views.
This issue is not introduced by the changes done for the aggregate push
down, it only got exposed as we now ship expressions in the target list.
Thus I think it will be good if we make these changes separately as new
patch, if required.
To me it is better to have expression in the GROUP BY clause as it is
more readable and easy to understand. Also it is in sync with deparsing
logic in ruleutils.c.Not exactly. get_rule_sortgroupclause() prints only the target list
positions instead of actual expression in GROUP BY or ORDER BY clause
if requested so. We could opt to do the same in all cases. But I think
it's better to add the whole expression in the remote query for
readability.
Right.
case
you do that, adjust capitalization accordingly.Moved testcases after Join testcases.
However I have not made any capitalization changes. I see many tests
like those elsewhere in the file too. Let me know if that's the policy
to have appropriate capitalization in test-case. I don't want violate
the policy if any and will prefer to do the changes as per the policy.This file has used different styles for different sets. But we usually
adopt the style from surrounding testcases. The testcases surrounding
aggregate testcase block are capitalized. It will look odd to have
just the aggregate tests using different style.
I see mixed use of capitalization in the file and use of it is adhoc too.
So not convinced with your argument yet. I don't think there is any policy
for that; otherwise use of capitalization in this file would have been
consistent already. Can we defer this to the committer's opinion.
Please use "foreign server" instead of "remote". + /* + * If aggregate's input collation is not derived from a foreign + * Var, it can't be sent to remote. + */
This is consistent with other nodetyps usage. see FuncExpr for example.
I guess, aggregate's input collation should consider aggfilter collation, since that doesn't affect aggregates collation. But we should make sure that aggfilter is safe to pushdown from collation's perspective. + /* Check aggregate filter */ + if (!foreign_expr_walker((Node *) agg->aggfilter, + glob_cxt, &inner_cxt)) + return false;
inner_cxt is a merger of all the args/expressions context which is then
checked with aggregate's input collation. So I believe aggfilter collation
is also verified as expected.
Am I missing anything here?
Fixed all other comments including test-cases changes as suggested.
[1] http://www.mail-archive.com/pgsql-hackers@postgresql.org/
msg295435.html
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Thanks
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Attachments:
pg_agg_push_down_v4.patchbinary/octet-stream; name=pg_agg_push_down_v4.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..79ac8a8 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -38,6 +38,7 @@
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/sysattr.h"
+#include "catalog/pg_aggregate.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_namespace.h"
#include "catalog/pg_operator.h"
@@ -56,6 +57,7 @@
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
/*
@@ -65,6 +67,7 @@ typedef struct foreign_glob_cxt
{
PlannerInfo *root; /* global planner state */
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ Relids relids; /* relids of the scan relation */
} foreign_glob_cxt;
/*
@@ -89,11 +92,16 @@ typedef struct foreign_loc_cxt
/*
* Context for deparseExpr
+ *
+ * When we are planning for an upper relation, then scanrel represents the
+ * underneath relation which is used to deparse FROM and WHERE. In all other
+ * cases, scanrel is same as foreignrel.
*/
typedef struct deparse_expr_cxt
{
PlannerInfo *root; /* global planner state */
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ RelOptInfo *scanrel; /* the underlying scan relation. */
StringInfo buf; /* output buffer to append to */
List **params_list; /* exprs that will become remote Params */
} deparse_expr_cxt;
@@ -135,7 +143,7 @@ static void deparseColumnRef(StringInfo buf, int varno, int varattno,
static void deparseRelation(StringInfo buf, Relation rel);
static void deparseExpr(Expr *expr, deparse_expr_cxt *context);
static void deparseVar(Var *node, deparse_expr_cxt *context);
-static void deparseConst(Const *node, deparse_expr_cxt *context);
+static void deparseConst(Const *node, deparse_expr_cxt *context, int showtype);
static void deparseParam(Param *node, deparse_expr_cxt *context);
static void deparseArrayRef(ArrayRef *node, deparse_expr_cxt *context);
static void deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context);
@@ -159,6 +167,14 @@ static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context);
static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *joinrel, bool use_alias, List **params_list);
+static void deparseFromExpr(List *quals, deparse_expr_cxt *context);
+static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
+static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
+static void appendAggOrderBy(List *orderList, List *targetList,
+ deparse_expr_cxt *context);
+static void appendFunctionName(Oid funcid, deparse_expr_cxt *context);
+static Node *deparseSortGroupClause(Index ref, List *tlist,
+ deparse_expr_cxt *context);
/*
@@ -200,6 +216,7 @@ is_foreign_expr(PlannerInfo *root,
{
foreign_glob_cxt glob_cxt;
foreign_loc_cxt loc_cxt;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) (baserel->fdw_private);
/*
* Check that the expression consists of nodes that are safe to execute
@@ -207,6 +224,14 @@ is_foreign_expr(PlannerInfo *root,
*/
glob_cxt.root = root;
glob_cxt.foreignrel = baserel;
+ /*
+ * For an upper relation, use relids from its underneath scan relation.
+ * For other relation, use their own relids.
+ */
+ if (baserel->reloptkind == RELOPT_UPPER_REL)
+ glob_cxt.relids = fpinfo->outerrel->relids;
+ else
+ glob_cxt.relids = baserel->relids;
loc_cxt.collation = InvalidOid;
loc_cxt.state = FDW_COLLATE_NONE;
if (!foreign_expr_walker((Node *) expr, &glob_cxt, &loc_cxt))
@@ -281,7 +306,7 @@ foreign_expr_walker(Node *node,
* Param's collation, ie it's not safe for it to have a
* non-default collation.
*/
- if (bms_is_member(var->varno, glob_cxt->foreignrel->relids) &&
+ if (bms_is_member(var->varno, glob_cxt->relids) &&
var->varlevelsup == 0)
{
/* Var belongs to foreign table */
@@ -631,6 +656,109 @@ foreign_expr_walker(Node *node,
check_type = false;
}
break;
+ case T_Aggref:
+ {
+ Aggref *agg = (Aggref *) node;
+ ListCell *lc;
+
+ /* Not safe to pushdown when not in grouping context */
+ if (glob_cxt->foreignrel->reloptkind != RELOPT_UPPER_REL)
+ return false;
+
+ /* Only non-split aggregates are pushable. */
+ if (agg->aggsplit != AGGSPLIT_SIMPLE)
+ return false;
+
+ /*
+ * If aggregate function used by the expression is not
+ * shippable, it can't be sent to remote because it might
+ * have incompatible semantics on remote side.
+ */
+ if (!is_shippable(agg->aggfnoid, ProcedureRelationId, fpinfo))
+ return false;
+
+ /*
+ * Recurse to input args. aggdirectargs, aggorder and
+ * aggdistinct are all present in args, so no need to
+ * check their shippability explicitly.
+ */
+ foreach(lc, agg->args)
+ {
+ Node *n = (Node *) lfirst(lc);
+
+ /* If TargetEntry, extract the expression from it */
+ if (IsA(n, TargetEntry))
+ {
+ TargetEntry *tle = (TargetEntry *) n;
+ n = (Node *) tle->expr;
+ }
+
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+
+ /*
+ * For aggorder elements, check whether the sort operator, if
+ * specified, is shippable or not.
+ */
+ if (agg->aggorder)
+ {
+ ListCell *lc;
+
+ foreach (lc, agg->aggorder)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+ TargetEntry *tle;
+
+ tle = get_sortgroupref_tle(srt->tleSortGroupRef,
+ agg->args);
+ sortcoltype = exprType((Node *) tle->expr);
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ /* Check shippability of non-default sort operator. */
+ if (srt->sortop != typentry->lt_opr &&
+ srt->sortop != typentry->gt_opr)
+ if (!is_shippable(srt->sortop, OperatorRelationId,
+ fpinfo))
+ return false;
+ }
+ }
+
+ /* Check aggregate filter */
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
+ if (agg->inputcollid == InvalidOid)
+ /* OK, inputs are all noncollatable */ ;
+ else if (inner_cxt.state != FDW_COLLATE_SAFE ||
+ agg->inputcollid != inner_cxt.collation)
+ return false;
+
+ /*
+ * Detect whether node is introducing a collation not derived
+ * from a foreign Var. (If so, we just mark it unsafe for now
+ * rather than immediately returning false, since the parent
+ * node might not care.)
+ */
+ collation = agg->aggcollid;
+ if (collation == InvalidOid)
+ state = FDW_COLLATE_NONE;
+ else if (inner_cxt.state == FDW_COLLATE_SAFE &&
+ collation == inner_cxt.collation)
+ state = FDW_COLLATE_SAFE;
+ else if (collation == DEFAULT_COLLATION_OID)
+ state = FDW_COLLATE_NONE;
+ else
+ state = FDW_COLLATE_UNSAFE;
+ }
+ break;
default:
/*
@@ -720,7 +848,9 @@ deparse_type_name(Oid type_oid, int32 typemod)
* Build the targetlist for given relation to be deparsed as SELECT clause.
*
* The output targetlist contains the columns that need to be fetched from the
- * foreign server for the given relation.
+ * foreign server for the given relation. If foreignrel is an upper relation,
+ * then the output targetlist can also contains expressions to be evaluated on
+ * foreign server.
*/
List *
build_tlist_to_deparse(RelOptInfo *foreignrel)
@@ -729,6 +859,13 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
/*
+ * For an upper relation, we have already built the target list while
+ * checking shippability, return that.
+ */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ return fpinfo->grouped_tlist;
+
+ /*
* We require columns specified in foreignrel->reltarget->exprs and those
* required for evaluating the local conditions.
*/
@@ -750,6 +887,7 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
* hence the tlist is ignored for a base relation.
*
* remote_conds is the list of conditions to be deparsed as WHERE clause.
+ * However for upper relation it is deparsed as HAVING clause.
*
* If params_list is not NULL, it receives a list of Params and other-relation
* Vars used in the clauses; these values must be transmitted to the remote
@@ -768,28 +906,56 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *)rel->fdw_private;
+ List *quals;
- /* We handle relations for foreign tables and joins between those */
+ /*
+ * We handle relations for foreign tables, joins between those and upper
+ * relations.
+ */
Assert(rel->reloptkind == RELOPT_JOINREL ||
rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
+ rel->reloptkind == RELOPT_UPPER_REL);
- /* Fill portions of context common to join and base relation */
+ /* Fill portions of context common to upper, join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ? fpinfo->outerrel : rel;
context.params_list = params_list;
- /* Construct SELECT clause and FROM clause */
+ /* Construct SELECT clause */
deparseSelectSql(tlist, retrieved_attrs, &context);
/*
- * Construct WHERE clause
+ * For upper relations, WHERE clause is built from the underneath scan
+ * relation's remote conditions.
*/
- if (remote_conds)
+ if (rel->reloptkind == RELOPT_UPPER_REL)
{
- appendStringInfo(buf, " WHERE ");
- appendConditions(remote_conds, &context);
+ PgFdwRelationInfo *ofpinfo;
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+ quals = ofpinfo->remote_conds;
+ }
+ else
+ quals = remote_conds;
+
+ /* Construct FROM and WHERE clauses */
+ deparseFromExpr(quals, &context);
+
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ {
+ /* Append GROUP BY clause */
+ appendGroupByClause(tlist, &context);
+
+ /* Append HAVING clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " HAVING ");
+ appendConditions(remote_conds, &context);
+ }
}
/* Add ORDER BY clause if we found any useful pathkeys */
@@ -803,7 +969,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
/*
* Construct a simple SELECT statement that retrieves desired columns
* of the specified foreign table, and append it to "buf". The output
- * contains just "SELECT ... FROM ....".
+ * contains just "SELECT ... ".
*
* We also create an integer List of the columns being retrieved, which is
* returned to *retrieved_attrs.
@@ -824,7 +990,8 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -847,14 +1014,39 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
+}
- /*
- * Construct FROM clause
- */
+/*
+ * Construct a FROM clause and a WHERE clause, if any, and append those to
+ * "buf".
+ *
+ * quals is the list of clauses to be included in the WHERE clause,
+ * NIL if none.
+ */
+static void
+deparseFromExpr(List *quals, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ RelOptInfo *foreignrel = context->foreignrel;
+ RelOptInfo *scanrel = context->scanrel;
+
+ /* For upper relations, scanrel must be either a joinrel or a baserel */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ Assert(scanrel->reloptkind == RELOPT_JOINREL ||
+ scanrel->reloptkind == RELOPT_BASEREL);
+
+ /* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, context->root, scanrel,
+ (bms_num_members(scanrel->relids) > 1),
context->params_list);
+
+ /* Construct WHERE clause */
+ if (quals)
+ {
+ appendStringInfo(buf, " WHERE ");
+ appendConditions(quals, context);
+ }
}
/*
@@ -957,14 +1149,14 @@ deparseTargetList(StringInfo buf,
/*
* Deparse the appropriate locking clause (FOR UPDATE or FOR SHARE) for a
- * given relation (context->foreignrel).
+ * given relation (context->scanrel).
*/
static void
deparseLockingClause(deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
PlannerInfo *root = context->root;
- RelOptInfo *rel = context->foreignrel;
+ RelOptInfo *rel = context->scanrel;
int relid = -1;
while ((relid = bms_next_member(rel->relids, relid)) >= 0)
@@ -1024,7 +1216,7 @@ deparseLockingClause(deparse_expr_cxt *context)
}
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL &&
+ if (bms_num_members(rel->relids) > 1 &&
rc->strength != LCS_NONE)
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
@@ -1036,7 +1228,7 @@ deparseLockingClause(deparse_expr_cxt *context)
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
- * deparse both WHERE clauses and JOIN .. ON clauses.
+ * deparse WHERE clauses, JOIN .. ON clauses and HAVING clauses.
*/
static void
appendConditions(List *exprs, deparse_expr_cxt *context)
@@ -1126,22 +1318,15 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
foreach(lc, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
- Var *var;
/* Extract expression if TargetEntry node */
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
-
- /* We expect only Var nodes here */
- if (!IsA(var, Var))
- elog(ERROR, "non-Var not expected in target list");
if (i > 0)
appendStringInfoString(buf, ", ");
- deparseVar(var, context);
+ deparseExpr((Expr *) tle->expr, context);
*retrieved_attrs = lappend_int(*retrieved_attrs, i + 1);
-
i++;
}
@@ -1192,6 +1377,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
context.buf = buf;
context.foreignrel = foreignrel;
+ context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
@@ -1360,6 +1546,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1444,6 +1631,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1817,7 +2005,7 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
deparseVar((Var *) node, context);
break;
case T_Const:
- deparseConst((Const *) node, context);
+ deparseConst((Const *) node, context, 0);
break;
case T_Param:
deparseParam((Param *) node, context);
@@ -1849,6 +2037,9 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
case T_ArrayExpr:
deparseArrayExpr((ArrayExpr *) node, context);
break;
+ case T_Aggref:
+ deparseAggref((Aggref *)node, context);
+ break;
default:
elog(ERROR, "unsupported expression type for deparse: %d",
(int) nodeTag(node));
@@ -1867,10 +2058,11 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ Relids relids = context->scanrel->relids;
+ /* Qualify columns when multiple relations are involved. */
+ bool qualify_col = (bms_num_members(relids) > 1) ? true : false;
- if (bms_is_member(node->varno, context->foreignrel->relids) &&
- node->varlevelsup == 0)
+ if (bms_is_member(node->varno, relids) && node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
else
@@ -1910,7 +2102,7 @@ deparseVar(Var *node, deparse_expr_cxt *context)
* This function has to be kept in sync with ruleutils.c's get_const_expr.
*/
static void
-deparseConst(Const *node, deparse_expr_cxt *context)
+deparseConst(Const *node, deparse_expr_cxt *context, int showtype)
{
StringInfo buf = context->buf;
Oid typoutput;
@@ -1922,9 +2114,10 @@ deparseConst(Const *node, deparse_expr_cxt *context)
if (node->constisnull)
{
appendStringInfoString(buf, "NULL");
- appendStringInfo(buf, "::%s",
- deparse_type_name(node->consttype,
- node->consttypmod));
+ if (showtype >= 0)
+ appendStringInfo(buf, "::%s",
+ deparse_type_name(node->consttype,
+ node->consttypmod));
return;
}
@@ -1974,9 +2167,14 @@ deparseConst(Const *node, deparse_expr_cxt *context)
break;
}
+ pfree(extval);
+
+ if (showtype < 0)
+ return;
+
/*
- * Append ::typename unless the constant will be implicitly typed as the
- * right type when it is read in.
+ * For showtype == 0, append ::typename unless the constant will be
+ * implicitly typed as the right type when it is read in.
*
* XXX this code has to be kept in sync with the behavior of the parser,
* especially make_const.
@@ -1995,7 +2193,7 @@ deparseConst(Const *node, deparse_expr_cxt *context)
needlabel = true;
break;
}
- if (needlabel)
+ if (needlabel || showtype > 0)
appendStringInfo(buf, "::%s",
deparse_type_name(node->consttype,
node->consttypmod));
@@ -2092,9 +2290,6 @@ static void
deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
- HeapTuple proctup;
- Form_pg_proc procform;
- const char *proname;
bool use_variadic;
bool first;
ListCell *arg;
@@ -2127,29 +2322,15 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
return;
}
- /*
- * Normal function: display as proname(args).
- */
- proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->funcid));
- if (!HeapTupleIsValid(proctup))
- elog(ERROR, "cache lookup failed for function %u", node->funcid);
- procform = (Form_pg_proc) GETSTRUCT(proctup);
-
/* Check if need to print VARIADIC (cf. ruleutils.c) */
use_variadic = node->funcvariadic;
- /* Print schema name only if it's not pg_catalog */
- if (procform->pronamespace != PG_CATALOG_NAMESPACE)
- {
- const char *schemaname;
-
- schemaname = get_namespace_name(procform->pronamespace);
- appendStringInfo(buf, "%s.", quote_identifier(schemaname));
- }
+ /*
+ * Normal function: display as proname(args).
+ */
+ appendFunctionName(node->funcid, context);
+ appendStringInfoChar(buf, '(');
- /* Deparse the function name ... */
- proname = NameStr(procform->proname);
- appendStringInfo(buf, "%s(", quote_identifier(proname));
/* ... and all the arguments */
first = true;
foreach(arg, node->args)
@@ -2162,8 +2343,6 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
first = false;
}
appendStringInfoChar(buf, ')');
-
- ReleaseSysCache(proctup);
}
/*
@@ -2420,6 +2599,152 @@ deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context)
}
/*
+ * Deparse an Aggref node.
+ */
+static void
+deparseAggref(Aggref *node, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ bool use_variadic;
+
+ /* Only basic, non-split aggregation accepted. */
+ Assert(node->aggsplit == AGGSPLIT_SIMPLE);
+
+ /* Check if need to print VARIADIC (cf. ruleutils.c) */
+ use_variadic = node->aggvariadic;
+
+ /* Find aggregate name from aggfnoid which is a pg_proc entry */
+ appendFunctionName(node->aggfnoid, context);
+ appendStringInfoChar(buf, '(');
+
+ /* Add DISTINCT */
+ appendStringInfo(buf, "%s", (node->aggdistinct != NIL) ? "DISTINCT " : "");
+
+ if (AGGKIND_IS_ORDERED_SET(node->aggkind))
+ {
+ /* Add WITHIN GROUP (ORDER BY ..) */
+ ListCell *arg;
+ bool first = true;
+
+ Assert(!node->aggvariadic);
+ Assert(node->aggorder != NIL);
+
+ foreach(arg, node->aggdirectargs)
+ {
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseExpr((Expr *) lfirst(arg), context);
+ }
+
+ appendStringInfoString(buf, ") WITHIN GROUP (ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ else
+ {
+ /* aggstar can be set only in zero-argument aggregates */
+ if (node->aggstar)
+ appendStringInfoChar(buf, '*');
+ else
+ {
+ ListCell *arg;
+ bool first = true;
+
+ /* ... and all the arguments */
+ foreach(arg, node->args)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(arg);
+ Node *n = (Node *) tle->expr;
+
+ if (tle->resjunk)
+ continue;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ /* Add VARIADIC */
+ if (use_variadic && lnext(arg) == NULL)
+ appendStringInfoString(buf, "VARIADIC ");
+
+ deparseExpr((Expr *) n, context);
+ }
+ }
+
+ /* Add ORDER BY */
+ if (node->aggorder != NIL)
+ {
+ appendStringInfoString(buf, " ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ }
+
+ /* Add FILTER (WHERE ..) */
+ if (node->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ deparseExpr((Expr *) node->aggfilter, context);
+ }
+
+ appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Append ORDER BY within aggregate function.
+ */
+static void
+appendAggOrderBy(List *orderList, List *targetList, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ ListCell *lc;
+ bool first = true;
+
+ foreach (lc, orderList)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Node *sortexpr;
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ sortexpr = deparseSortGroupClause(srt->tleSortGroupRef, targetList,
+ context);
+ sortcoltype = exprType(sortexpr);
+ /* See whether operator is default < or > for datatype */
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ if (srt->sortop == typentry->lt_opr)
+ appendStringInfoString(buf, " ASC");
+ else if (srt->sortop == typentry->gt_opr)
+ appendStringInfoString(buf, " DESC");
+ else
+ {
+ HeapTuple opertup;
+ Form_pg_operator operform;
+
+ appendStringInfoString(buf, " USING ");
+
+ /* Append operator name. */
+ opertup = SearchSysCache1(OPEROID, ObjectIdGetDatum(srt->sortop));
+ if (!HeapTupleIsValid(opertup))
+ elog(ERROR, "cache lookup failed for operator %u", srt->sortop);
+ operform = (Form_pg_operator) GETSTRUCT(opertup);
+ deparseOperatorName(buf, operform);
+ ReleaseSysCache(opertup);
+ }
+
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ else
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+}
+
+/*
* Print the representation of a parameter to be sent to the remote side.
*
* Note: we always label the Param's type explicitly rather than relying on
@@ -2464,6 +2789,41 @@ printRemotePlaceholder(Oid paramtype, int32 paramtypmod,
}
/*
+ * Deparse GROUP BY clause.
+ */
+static void
+appendGroupByClause(List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ Query *query = context->root->parse;
+ ListCell *lc;
+ bool first = true;
+
+ /* Nothing to be done, if there's no GROUP BY clause in the query. */
+ if (!query->groupClause)
+ return;
+
+ appendStringInfo(buf, " GROUP BY ");
+
+ /*
+ * Queries with grouping sets are not pushed down, so we don't expect
+ * grouping sets here.
+ */
+ Assert(!query->groupingSets);
+
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseSortGroupClause(grp->tleSortGroupRef, tlist, context);
+ }
+}
+
+/*
* Deparse ORDER BY clause according to the given pathkeys for given base
* relation. From given pathkeys expressions belonging entirely to the given
* base relation are obtained and deparsed.
@@ -2474,7 +2834,7 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
ListCell *lcell;
int nestlevel;
char *delim = " ";
- RelOptInfo *baserel = context->foreignrel;
+ RelOptInfo *baserel = context->scanrel;
StringInfo buf = context->buf;
/* Make sure any constants in the exprs are printed portably */
@@ -2505,3 +2865,67 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
}
reset_transmission_modes(nestlevel);
}
+
+/*
+ * appendFunctionName
+ * Deparses function name from given function oid.
+ */
+static void
+appendFunctionName(Oid funcid, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ HeapTuple proctup;
+ Form_pg_proc procform;
+ const char *proname;
+
+ proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
+ if (!HeapTupleIsValid(proctup))
+ elog(ERROR, "cache lookup failed for function %u", funcid);
+ procform = (Form_pg_proc) GETSTRUCT(proctup);
+
+ /* Print schema name only if it's not pg_catalog */
+ if (procform->pronamespace != PG_CATALOG_NAMESPACE)
+ {
+ const char *schemaname;
+
+ schemaname = get_namespace_name(procform->pronamespace);
+ appendStringInfo(buf, "%s.", quote_identifier(schemaname));
+ }
+
+ /* Deparse the function name ... */
+ proname = NameStr(procform->proname);
+ appendStringInfo(buf, "%s", quote_identifier(proname));
+
+ ReleaseSysCache(proctup);
+}
+
+/*
+ * Appends a sort or group clause.
+ *
+ * Like get_rule_sortgroupclause(), returns the expression tree, so caller
+ * need not find it again.
+ */
+static Node *
+deparseSortGroupClause(Index ref, List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ TargetEntry *tle;
+ Expr *expr;
+
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context, 1);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Always parenthesize the expression. */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+
+ return (Node *) expr;
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d97e694..9ad9795 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,14 +861,13 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
---------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
-(5 rows)
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
count
@@ -878,14 +877,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
----------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = c2))
-(5 rows)
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
count
@@ -937,14 +935,13 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
-----------------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
count
@@ -954,14 +951,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
count
@@ -2283,6 +2279,1138 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Result
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ -> Sort
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Sort Key: (count(ft1.c6)), (sum(ft1.c1))
+ -> Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY c2
+(9 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Sort Key: ((ft1.c2 / 2))
+ -> Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
+(7 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Sort
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Sort Key: ft1.c2, (sum(ft1.c1))
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
+(9 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause referencing position in the select list and also testing alias used along with numeric constant
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, (5), (7.0), (9)
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, (5), (7.0), (9)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY c2, 5::integer, 9::integer
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800))
+(7 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Sort Key: ft1.c5, (count(ft1.c2))
+ -> Foreign Scan
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) = 1.41421356237309515::double precision))
+(7 rows)
+
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Sat Jan 03 00:00:00 1970 | 10
+ Tue Jan 13 00:00:00 1970 | 10
+ Fri Jan 23 00:00:00 1970 | 10
+ Mon Feb 02 00:00:00 1970 | 10
+ Thu Feb 12 00:00:00 1970 | 10
+ Sun Feb 22 00:00:00 1970 | 10
+ Wed Mar 04 00:00:00 1970 | 10
+ Sat Mar 14 00:00:00 1970 | 10
+ Tue Mar 24 00:00:00 1970 | 10
+ Fri Apr 03 00:00:00 1970 | 10
+(10 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Sort Key: (array_agg(ft1.c1 ORDER BY ft1.c1))
+ -> Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
+(7 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY "C 1", c2
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t2
+ Remote SQL: SELECT NULL FROM "S 1"."T 1"
+ -> Materialize
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(11 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
+(20 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Sort Key: (avg(t1.c1)), (sum(t2.c1))
+ -> Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
+(7 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Seq Scan on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Filter: (t1.c2 < 10)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(15 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+ 3 | 6
+ 4 | 8
+ 5 | 10
+ 6 | 12
+ 7 | 14
+ 8 | 16
+ 9 | 18
+(9 rows)
+
+reset enable_hashagg;
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: q.b, (count(ft4.c1)), (sum(q.a))
+ Sort Key: q.b, (count(ft4.c1))
+ -> GroupAggregate
+ Output: q.b, count(ft4.c1), sum(q.a)
+ Group Key: q.b
+ -> Sort
+ Output: q.b, ft4.c1, q.a
+ Sort Key: q.b
+ -> Hash Left Join
+ Output: q.b, ft4.c1, q.a
+ Hash Cond: ((ft4.c1)::numeric = q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Hash
+ Output: q.b, q.a
+ -> Subquery Scan on q
+ Output: q.b, q.a
+ -> Foreign Scan
+ Output: (min(13)), (avg(ft1.c1)), (NULL::bigint)
+ Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
+ Remote SQL: SELECT min(13), avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
+(23 rows)
+
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ b | count | sum
+---------------------+-------+-----
+ 12.0000000000000000 | 1 | 13
+ | 2 |
+(2 rows)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> GroupAggregate
+ Output: c2, c6, sum(c1)
+ Group Key: ft1.c2
+ Sort Key: ft1.c6
+ Group Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
-- parameterized queries
-- ===================================================================
-- simple join
@@ -2608,6 +3736,9 @@ CONTEXT: column "c8" of foreign table "ft1"
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
ERROR: invalid input syntax for integer: "foo"
CONTEXT: whole-row reference to foreign table "ft1"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for integer: "foo"
+CONTEXT: processing expression at position 2 in select list
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
-- subtransaction
@@ -4441,12 +5572,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
--------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4485,12 +5616,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
---------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..499b6cc 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -25,6 +25,7 @@
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/cost.h"
+#include "optimizer/clauses.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
@@ -38,6 +39,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/sampling.h"
+#include "utils/selfuncs.h"
PG_MODULE_MAGIC;
@@ -343,6 +345,10 @@ static void postgresGetForeignJoinPaths(PlannerInfo *root,
JoinPathExtraData *extra);
static bool postgresRecheckForeignScan(ForeignScanState *node,
TupleTableSlot *slot);
+static void postgresGetForeignUpperPaths(PlannerInfo *root,
+ UpperRelationKind stage,
+ RelOptInfo *input_rel,
+ RelOptInfo *output_rel);
/*
* Helper functions
@@ -400,11 +406,15 @@ static void conversion_error_callback(void *arg);
static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel,
JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinPathExtraData *extra);
+static bool foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel);
static List *get_useful_pathkeys_for_relation(PlannerInfo *root,
RelOptInfo *rel);
static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel);
static void add_paths_with_pathkeys_for_rel(PlannerInfo *root, RelOptInfo *rel,
Path *epq_path);
+static void add_foreign_grouping_paths(PlannerInfo *root,
+ RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel);
/*
@@ -455,6 +465,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
/* Support functions for join push-down */
routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+ /* Support functions for upper relation push-down */
+ routine->GetForeignUpperPaths = postgresGetForeignUpperPaths;
+
PG_RETURN_POINTER(routine);
}
@@ -1120,7 +1133,7 @@ postgresGetForeignPlan(PlannerInfo *root,
* rel->baserestrictinfo + parameterization clauses through
* scan_clauses. For a join rel->baserestrictinfo is NIL and we are
* not considering parameterization right now, so there should be no
- * scan_clauses for a joinrel.
+ * scan_clauses for a joinrel and upper rel either.
*/
Assert(!scan_clauses);
}
@@ -1170,7 +1183,8 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1191,6 +1205,13 @@ postgresGetForeignPlan(PlannerInfo *root,
{
ListCell *lc;
+ /*
+ * Right now, we only consider grouping and aggregation beyond
+ * joins. Queries involving aggregates or grouping do not require
+ * EPQ mechanism, hence should not have an outer plan here.
+ */
+ Assert(foreignrel->reloptkind != RELOPT_UPPER_REL);
+
outer_plan->targetlist = fdw_scan_tlist;
foreach(lc, local_exprs)
@@ -1228,7 +1249,8 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2452,7 +2474,8 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
/*
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
- * either a base relation or a join between foreign relations.
+ * either a base relation or a join between foreign relations or an upper
+ * relation containing foreign relations.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -2505,7 +2528,8 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,25 +2610,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
- {
- /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
- retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
-
- /*
- * Cost as though this were a seqscan, which is pessimistic. We
- * effectively imagine the local_conds are being evaluated
- * remotely, too.
- */
- startup_cost = 0;
- run_cost = 0;
- run_cost += seq_page_cost * foreignrel->pages;
-
- startup_cost += foreignrel->baserestrictcost.startup;
- cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
- run_cost += cpu_per_tuple * foreignrel->tuples;
- }
- else
+ else if (foreignrel->reloptkind == RELOPT_JOINREL)
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
@@ -2670,6 +2676,97 @@ estimate_path_cost_size(PlannerInfo *root,
run_cost += nrows * remote_conds_cost.per_tuple;
run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows;
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+ AggClauseCosts aggcosts;
+ double input_rows;
+ int numGroupCols;
+ double numGroups = 1;
+
+ /*
+ * This cost model is mixture of costing done for sorted and hashed
+ * aggregates in cost_agg(). We are not sure which strategy will
+ * be considered at remote side, thus for simplicity, we put all
+ * startup related costs in startup_cost and all finalization and
+ * run cost are added in total_cost.
+ *
+ * Also, core does not care about costing HAVING expressions and
+ * adding that to the costs. So similarly, here too we are not
+ * considering remote and local conditions for costing.
+ */
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /* Get rows and width from input rel */
+ input_rows = ofpinfo->rows;
+ width = ofpinfo->width;
+
+ /* Collect statistics about aggregates for estimating costs. */
+ MemSet(&aggcosts, 0, sizeof(AggClauseCosts));
+ if (root->parse->hasAggs)
+ {
+ get_agg_clause_costs(root, (Node *) fpinfo->grouped_tlist,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ get_agg_clause_costs(root, (Node *) root->parse->havingQual,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ }
+
+ /* Get number of grouping columns and possible number of groups */
+ numGroupCols = list_length(root->parse->groupClause);
+ numGroups = estimate_num_groups(root,
+ get_sortgrouplist_exprs(root->parse->groupClause,
+ fpinfo->grouped_tlist),
+ input_rows, NULL);
+
+ /*
+ * Number of rows expected from foreign server will be same as that
+ * of number of groups.
+ */
+ rows = retrieved_rows = numGroups;
+
+ /*
+ * Startup cost includes:
+ * 1. Startup cost for underneath input relation
+ * 2. Cost of performing aggregation, per cost_agg()
+ * 3. Startup cost for PathTarget eval
+ */
+ startup_cost = ofpinfo->rel_startup_cost;
+ startup_cost += aggcosts.transCost.startup;
+ startup_cost += aggcosts.transCost.per_tuple * input_rows;
+ startup_cost += (cpu_operator_cost * numGroupCols) * input_rows;
+ startup_cost += ptarget->cost.startup;
+
+ /*
+ * Run time cost includes:
+ * 1. Run time cost of underneath input relation
+ * 2. Run time cost of performing aggregation, per cost_agg()
+ * 4. PathTarget eval cost for each output row
+ */
+ run_cost = ofpinfo->rel_total_cost - ofpinfo->rel_startup_cost;
+ run_cost += aggcosts.finalCost * numGroups;
+ run_cost += cpu_tuple_cost * numGroups;
+ run_cost += ptarget->cost.per_tuple * numGroups;
+ }
+ else
+ {
+ /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
+ retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
+
+ /*
+ * Cost as though this were a seqscan, which is pessimistic. We
+ * effectively imagine the local_conds are being evaluated
+ * remotely, too.
+ */
+ startup_cost = 0;
+ run_cost = 0;
+ run_cost += seq_page_cost * foreignrel->pages;
+
+ startup_cost += foreignrel->baserestrictcost.startup;
+ cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
+ run_cost += cpu_per_tuple * foreignrel->tuples;
+ }
/*
* Without remote estimates, we have no real way to estimate the cost
@@ -4343,6 +4440,328 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
}
/*
+ * Assess whether the aggregation, grouping and having operations can be pushed
+ * down to the foreign server. As a side effect, save information we obtain in
+ * this function to PgFdwRelationInfo of the input relation.
+ */
+static bool
+foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
+{
+ Query *query = root->parse;
+ PathTarget *grouping_target;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) grouped_rel->fdw_private;
+ PgFdwRelationInfo *ofpinfo;
+ List *aggvars;
+ ListCell *lc;
+ int i;
+ List *tlist = NIL;
+
+ /* Grouping Sets are not pushable */
+ if (query->groupingSets)
+ return false;
+
+ /* Get the fpinfo of the underlying scan relation. */
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /*
+ * If underneath input relation has any local conditions, those conditions
+ * are required to be applied before performing aggregation. Hence the
+ * aggregate cannot be pushed down.
+ */
+ if (ofpinfo->local_conds)
+ return false;
+
+ /*
+ * We may need to modify the sortgrouprefs from path target, thus copy it
+ * so that we will not have any undesired effect. We need to modify the
+ * sortgrouprefs when it points to one of the ORDER BY expression but not
+ * to any GROUP BY expression and that expression is not pushed as is.
+ * If we do not clear such entries, then we will end up into an error later
+ * when we adjust the sortgrouprefs in the PathTarget according to new
+ * targetlist saying, order or group by expression not found in the
+ * targetlist.
+ */
+ grouping_target = copy_pathtarget(root->upper_targets[UPPERREL_GROUP_AGG]);
+
+ /*
+ * Evaluate grouping targets and check whether they are safe to push down
+ * to the foreign side. All GROUP BY expressions will be part of the
+ * grouping target and thus there is no need to evaluate it separately.
+ * While doing so, add required expressions into target list which
+ * can then be used to pass to foreign server.
+ */
+ i = 0;
+ foreach(lc, grouping_target->exprs)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+ Index sgref = get_pathtarget_sortgroupref(grouping_target, i);
+ ListCell *l;
+
+ /* Check whether this expression is part of GROUP BY clause */
+ if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause))
+ {
+ /*
+ * If any of the GROUP BY expression is not shippable we can not
+ * push down aggregation to the foreign server.
+ */
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* Check entire expression whether it is pushable or not */
+ if (is_foreign_expr(root, grouped_rel, expr))
+ {
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /*
+ * If we have sortgroupref set, then it means that we have an
+ * ORDER BY entry pointing to this expression. Since we are
+ * not pushing ORDER BY with GROUP BY, clear it.
+ */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
+
+ /* Not matched exactly, pull the var with aggregates then */
+ aggvars = pull_var_clause((Node *) expr,
+ PVC_INCLUDE_AGGREGATES);
+
+ if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars))
+ return false;
+
+ /*
+ * Add aggregates, if any, into the targetlist. Plain var
+ * nodes should be either same as some GROUP BY expression or
+ * part of some GROUP BY expression. In later case, the query
+ * cannot refer plain var nodes without the surrounding
+ * expression. In both the cases, they are already part of
+ * the targetlist and thus no need to add them again. In fact
+ * adding pulled plain var nodes in SELECT clause will cause
+ * an error on the foreign server if they are not same as some
+ * GROUP BY expression.
+ */
+ foreach(l, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(l);
+
+ if (IsA(expr, Aggref))
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ }
+ }
+
+ i++;
+ }
+
+ /*
+ * Classify the pushable and non-pushable having clauses and save them in
+ * remote_conds and local_conds of grouped_rel::fpinfo.
+ */
+ if (root->hasHavingQual && query->havingQual)
+ {
+ ListCell *lc;
+
+ foreach(lc, (List *) query->havingQual)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
+ else
+ fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
+ }
+ }
+
+ /*
+ * If there are any local conditions, pull Vars and aggregates from it and
+ * check whether they are safe to pushdown or not.
+ */
+ if (fpinfo->local_conds)
+ {
+ ListCell *lc;
+ List *aggvars = pull_var_clause((Node *) fpinfo->local_conds,
+ PVC_INCLUDE_AGGREGATES);
+
+ foreach(lc, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ /*
+ * If aggregates within local conditions are not safe to push down,
+ * then we cannot push down the query. Vars are already part of
+ * GROUP BY clause which are checked above, so no need to access
+ * them again here.
+ */
+ if (IsA(expr, Aggref))
+ {
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ tlist = add_to_flat_tlist(tlist, aggvars);
+ }
+ }
+ }
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, grouping_target);
+ /* Store generated targetlist */
+ fpinfo->grouped_tlist = tlist;
+
+ /* Safe to pushdown */
+ fpinfo->pushdown_safe = true;
+
+ /*
+ * If user is willing to estimate cost for a scan using EXPLAIN, he intends
+ * to estimate scans on that relation more accurately. Then, it makes sense
+ * to estimate the cost of the grouping on that relation more accurately
+ * using EXPLAIN.
+ */
+ fpinfo->use_remote_estimate = ofpinfo->use_remote_estimate;
+
+ /* Copy startup and tuple cost as is from underneath input rel's fpinfo */
+ fpinfo->fdw_startup_cost = ofpinfo->fdw_startup_cost;
+ fpinfo->fdw_tuple_cost = ofpinfo->fdw_tuple_cost;
+
+ /*
+ * Set cached relation costs to some negative value, so that we can detect
+ * when they are set to some sensible costs, during one (usually the
+ * first) of the calls to estimate_path_cost_size().
+ */
+ fpinfo->rel_startup_cost = -1;
+ fpinfo->rel_total_cost = -1;
+
+ /* Set fetch size same as that of underneath input rel's fpinfo */
+ fpinfo->fetch_size = ofpinfo->fetch_size;
+
+ /*
+ * Set the string describing this grouped relation to be used in EXPLAIN
+ * output of corresponding ForeignScan.
+ */
+ fpinfo->relation_name = makeStringInfo();
+ appendStringInfo(fpinfo->relation_name, "Aggregate on (%s)",
+ ofpinfo->relation_name->data);
+
+ return true;
+}
+
+/*
+ * postgresGetForeignUpperPaths
+ * Add paths for post-join operations like aggregation, grouping etc. if
+ * corresponding operations are safe to push down.
+ *
+ * Right now, we only support aggregate, grouping and having clause pushdown.
+ */
+static void
+postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
+ RelOptInfo *input_rel, RelOptInfo *output_rel)
+{
+ PgFdwRelationInfo *fpinfo;
+
+ /*
+ * If input rel is not safe to pushdown, then simply return as we cannot
+ * perform any post-join operations on the foreign server.
+ */
+ if (!input_rel->fdw_private ||
+ !((PgFdwRelationInfo *) input_rel->fdw_private)->pushdown_safe)
+ return;
+
+ /*
+ * This should not happen normally. In case we have already added paths for
+ * this output rel, nothing to be done again.
+ */
+ if (output_rel->fdw_private)
+ return;
+
+ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+ fpinfo->pushdown_safe = false;
+ output_rel->fdw_private = fpinfo;
+
+ if (stage == UPPERREL_GROUP_AGG)
+ return add_foreign_grouping_paths(root, input_rel, output_rel);
+
+ /* If it's anything else, we are not adding any foreign path. */
+ return;
+}
+
+/*
+ * add_foreign_grouping_paths
+ * Add foreign path for grouping and/or aggregation.
+ *
+ * Given input_rel represents the underlying scan. The paths are added to the
+ * given grouped_rel.
+ */
+static void
+add_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel)
+{
+ Query *parse = root->parse;
+ PgFdwRelationInfo *ifpinfo = input_rel->fdw_private;
+ PgFdwRelationInfo *fpinfo = grouped_rel->fdw_private;
+ ForeignPath *grouppath;
+ PathTarget *grouping_target;
+ double rows;
+ int width;
+ Cost startup_cost;
+ Cost total_cost;
+
+ /* Nothing to be done, if there is no grouping or aggregation required. */
+ if (!parse->groupClause && !parse->groupingSets && !parse->hasAggs &&
+ !root->hasHavingQual)
+ return;
+
+ grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /* save the input_rel as outerrel in fpinfo */
+ fpinfo->outerrel = input_rel;
+
+ /*
+ * Copy foreign table, foreign server, user mapping, shippable extensions
+ * etc. details from underneath input relation's fpinfo.
+ */
+ fpinfo->table = ifpinfo->table;
+ fpinfo->server = ifpinfo->server;
+ fpinfo->user = ifpinfo->user;
+ fpinfo->shippable_extensions = ifpinfo->shippable_extensions;
+
+ /* Assess if it is safe to push down aggregation and grouping. */
+ if (!foreign_grouping_ok(root, grouped_rel))
+ return;
+
+ /* Estimate the cost of push down */
+ estimate_path_cost_size(root, grouped_rel, NIL, NIL, &rows,
+ &width, &startup_cost, &total_cost);
+
+ /* Now update this information in the fpinfo */
+ fpinfo->rows = rows;
+ fpinfo->width = width;
+ fpinfo->startup_cost = startup_cost;
+ fpinfo->total_cost = total_cost;
+
+ /* Create and add foreign path to the grouping relation. */
+ grouppath = create_foreignscan_path(root,
+ grouped_rel,
+ grouping_target,
+ rows,
+ startup_cost,
+ total_cost,
+ NIL, /* no pathkeys */
+ NULL, /* no required_outer */
+ NULL,
+ NULL); /* no fdw_private */
+
+ /* Add generated path into grouped_rel by add_path(). */
+ add_path(grouped_rel, (Path *) grouppath);
+
+ return;
+}
+
+/*
* Create a tuple from the specified row of the PGresult.
*
* rel is the local representation of the foreign table, attinmeta is
@@ -4549,24 +4968,34 @@ conversion_error_callback(void *arg)
ForeignScan *fsplan = (ForeignScan *) fsstate->ss.ps.plan;
EState *estate = fsstate->ss.ps.state;
TargetEntry *tle;
- Var *var;
- RangeTblEntry *rte;
Assert(IsA(fsplan, ForeignScan));
tle = (TargetEntry *) list_nth(fsplan->fdw_scan_tlist,
errpos->cur_attno - 1);
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
- Assert(IsA(var, Var));
- rte = rt_fetch(var->varno, estate->es_range_table);
+ /*
+ * Target list can have Vars and expressions. For Vars, we can get
+ * it's relation, however for expressions we can't. Thus for
+ * expressions, just show generic context message.
+ */
+ if (IsA(tle->expr, Var))
+ {
+ RangeTblEntry *rte;
+ Var *var = (Var *) tle->expr;
- if (var->varattno == 0)
- is_wholerow = true;
- else
- attname = get_relid_attribute_name(rte->relid, var->varattno);
+ rte = rt_fetch(var->varno, estate->es_range_table);
+
+ if (var->varattno == 0)
+ is_wholerow = true;
+ else
+ attname = get_relid_attribute_name(rte->relid, var->varattno);
- relname = get_rel_name(rte->relid);
+ relname = get_rel_name(rte->relid);
+ }
+ else
+ errcontext("processing expression at position %d in select list",
+ errpos->cur_attno);
}
if (relname)
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 67126bc..f8c255e 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -92,6 +92,9 @@ typedef struct PgFdwRelationInfo
RelOptInfo *innerrel;
JoinType jointype;
List *joinclauses;
+
+ /* Grouping information */
+ List *grouped_tlist;
} PgFdwRelationInfo;
/* in postgres_fdw.c */
@@ -155,7 +158,7 @@ extern void deparseAnalyzeSql(StringInfo buf, Relation rel,
List **retrieved_attrs);
extern void deparseStringLiteral(StringInfo buf, const char *val);
extern Expr *find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel);
-extern List *build_tlist_to_deparse(RelOptInfo *foreign_rel);
+extern List *build_tlist_to_deparse(RelOptInfo *foreignrel);
extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, List *tlist,
List *remote_conds, List *pathkeys,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f68e89..7485b93 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -541,6 +541,310 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
+
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+
+-- GROUP BY clause referencing position in the select list and also testing alias used along with numeric constant
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+
+
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+
+create operator family my_op_family using btree;
+
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+reset enable_hashagg;
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+
+
-- ===================================================================
-- parameterized queries
-- ===================================================================
@@ -624,6 +928,7 @@ ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
SELECT * FROM ft1 WHERE c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1.c8 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 47158f6..76d402e 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -3243,8 +3243,15 @@ create_foreignscan_plan(PlannerInfo *root, ForeignPath *best_path,
/* Copy foreign server OID; likewise, no need to make FDW do this */
scan_plan->fs_server = rel->serverid;
- /* Likewise, copy the relids that are represented by this foreign scan */
- scan_plan->fs_relids = best_path->path.parent->relids;
+ /*
+ * Likewise, copy the relids that are represented by this foreign scan.
+ * For an upper rel, we don't have relids set, and thus use root's
+ * all_baserels instead
+ */
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ scan_plan->fs_relids = root->all_baserels;
+ else
+ scan_plan->fs_relids = best_path->path.parent->relids;
/*
* If this is a foreign join, and to make it valid to push down we had to
avoid_unnecessary_parens_for_ForeignScan_in_ruleutils.patchbinary/octet-stream; name=avoid_unnecessary_parens_for_ForeignScan_in_ruleutils.patchDownload
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 9ad9795..fa3400d 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -827,8 +827,8 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
-------------------------------------------------------------------------------
Sort
- Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
- Sort Key: ft2.c1, (random())
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Sort Key: ft2.c1, random()
-> Foreign Scan on public.ft2
Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
@@ -839,7 +839,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
-------------------------------------------------------------------------------
Sort
- Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (c3)::text
Sort Key: ft2.c1, ft2.c3 COLLATE "C"
-> Foreign Scan on public.ft2
Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
@@ -864,7 +864,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
---------------------------------------------------------------------------
Foreign Scan
- Output: (count(c3))
+ Output: count(c3)
Relations: Aggregate on (public.ft1 t1)
Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
(4 rows)
@@ -880,7 +880,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
----------------------------------------------------------------------
Foreign Scan
- Output: (count(c3))
+ Output: count(c3)
Relations: Aggregate on (public.ft1 t1)
Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
(4 rows)
@@ -938,7 +938,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
-----------------------------------------------------------------------------------------------
Foreign Scan
- Output: (count(c3))
+ Output: count(c3)
Relations: Aggregate on (public.ft1 t1)
Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
(4 rows)
@@ -954,7 +954,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
QUERY PLAN
-----------------------------------------------------------------------------------------
Foreign Scan
- Output: (count(c3))
+ Output: count(c3)
Relations: Aggregate on (public.ft1 t1)
Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
(4 rows)
@@ -2065,13 +2065,13 @@ SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 O
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------
Nested Loop Left Join
- Output: (13), ft2.c1
+ Output: 13, ft2.c1
Join Filter: (13 = ft2.c1)
-> Foreign Scan on public.ft2
Output: ft2.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
-> Materialize
- Output: (13)
+ Output: 13
-> Foreign Scan on public.ft1
Output: 13
Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
@@ -2094,13 +2094,13 @@ SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Nested Loop Left Join
- Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Output: ft4.c1, 13, ft1.c1, ft2.c1
Join Filter: (ft4.c1 = ft1.c1)
-> Foreign Scan on public.ft4
Output: ft4.c1, ft4.c2, ft4.c3
Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
-> Materialize
- Output: ft1.c1, ft2.c1, (13)
+ Output: ft1.c1, ft2.c1, 13
-> Foreign Scan
Output: ft1.c1, ft2.c1, 13
Relations: (public.ft1) INNER JOIN (public.ft2)
@@ -2287,12 +2287,12 @@ select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (ran
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------
Result
- Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Output: count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), (sum(c1) * ((random() <= '1'::double precision))::integer), c2
-> Sort
- Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
- Sort Key: (count(ft1.c6)), (sum(ft1.c1))
+ Output: count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), c2
+ Sort Key: count(ft1.c6), sum(ft1.c1)
-> Foreign Scan
- Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Output: count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY c2
(9 rows)
@@ -2325,7 +2325,7 @@ select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
- Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Output: count(*), sum(t1.c1), avg(t2.c1)
Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
(4 rows)
@@ -2356,10 +2356,10 @@ select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
QUERY PLAN
------------------------------------------------------------------------------------------------
Sort
- Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
- Sort Key: ((ft1.c2 / 2))
+ Output: (c2 / 2), (sum(c2) * (c2 / 2))
+ Sort Key: (ft1.c2 / 2)
-> Foreign Scan
- Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Output: (c2 / 2), (sum(c2) * (c2 / 2))
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
(7 rows)
@@ -2382,10 +2382,10 @@ select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, s
Aggregate
Output: count(ft1.c2), sum(ft1.c2)
-> Sort
- Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
- Sort Key: ft1.c2, (sum(ft1.c1))
+ Output: ft1.c2, sum(ft1.c1), sqrt((ft1.c1)::double precision)
+ Sort Key: ft1.c2, sum(ft1.c1)
-> Foreign Scan
- Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Output: ft1.c2, sum(ft1.c1), sqrt((ft1.c1)::double precision)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
(9 rows)
@@ -2399,13 +2399,13 @@ select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, s
-- Aggregate is still pushed down by taking unshippable expression out
explain (verbose, costs off)
select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
- QUERY PLAN
----------------------------------------------------------------------------------------------------
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
Sort
- Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
- Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ Output: (c2 * ((random() <= '1'::double precision))::integer), (sum(c1) * c2), c2
+ Sort Key: (ft1.c2 * ((random() <= '1'::double precision))::integer), (sum(ft1.c1) * ft1.c2)
-> Foreign Scan
- Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Output: (c2 * ((random() <= '1'::double precision))::integer), (sum(c1) * c2), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY c2
(7 rows)
@@ -2431,10 +2431,10 @@ select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::i
QUERY PLAN
------------------------------------------------------------------------------
Sort
- Output: ((c2 * ((random() <= '1'::double precision))::integer))
- Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Sort Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
-> HashAggregate
- Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
-> Foreign Scan on public.ft2
Output: (c2 * ((random() <= '1'::double precision))::integer)
@@ -2447,10 +2447,10 @@ select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2
QUERY PLAN
----------------------------------------------------------------------------------------------------------
Sort
- Output: (count(c2)), c2, (5), (7.0), (9)
+ Output: count(c2), c2, 5, 7.0, 9
Sort Key: ft1.c2
-> Foreign Scan
- Output: (count(c2)), c2, (5), (7.0), (9)
+ Output: count(c2), c2, 5, 7.0, 9
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY c2, 5::integer, 9::integer
(7 rows)
@@ -2476,10 +2476,10 @@ select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: c2, (sum(c1))
+ Output: c2, sum(c1)
Sort Key: ft2.c2
-> Foreign Scan
- Output: c2, (sum(c1))
+ Output: c2, sum(c1)
Relations: Aggregate on (public.ft2)
Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800))
(7 rows)
@@ -2497,10 +2497,10 @@ select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: c5, (count(c2)), (sqrt((c2)::double precision))
- Sort Key: ft1.c5, (count(ft1.c2))
+ Output: c5, count(c2), sqrt((c2)::double precision)
+ Sort Key: ft1.c5, count(ft1.c2)
-> Foreign Scan
- Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Output: c5, count(c2), sqrt((c2)::double precision)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) = 1.41421356237309515::double precision))
(7 rows)
@@ -2528,8 +2528,8 @@ select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having
Aggregate
Output: count(*)
-> Foreign Scan
- Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
- Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Output: ft1.c5, NULL::bigint, sqrt((ft1.c2)::double precision)
+ Filter: ((((avg(ft1.c1) / avg(ft1.c1)))::double precision * random()) <= '1'::double precision)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
(7 rows)
@@ -2564,10 +2564,10 @@ select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: (array_agg(c1 ORDER BY c1)), c2
- Sort Key: (array_agg(ft1.c1 ORDER BY ft1.c1))
+ Output: array_agg(c1 ORDER BY c1), c2
+ Sort Key: array_agg(ft1.c1 ORDER BY ft1.c1)
-> Foreign Scan
- Output: (array_agg(c1 ORDER BY c1)), c2
+ Output: array_agg(c1 ORDER BY c1), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
(7 rows)
@@ -2593,7 +2593,7 @@ select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------
Foreign Scan
- Output: (array_agg(c5 ORDER BY c1 DESC))
+ Output: array_agg(c5 ORDER BY c1 DESC)
Relations: Aggregate on (public.ft2)
Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
(4 rows)
@@ -2610,10 +2610,10 @@ select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
- Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ Output: array_agg(DISTINCT (t1.c1 % 5)), (t2.c1 % 3)
+ Sort Key: array_agg(DISTINCT (t1.c1 % 5))
-> Foreign Scan
- Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Output: array_agg(DISTINCT (t1.c1 % 5)), (t2.c1 % 3)
Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
(7 rows)
@@ -2631,10 +2631,10 @@ select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
- Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ Output: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)), (t2.c1 % 3)
+ Sort Key: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))
-> Foreign Scan
- Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Output: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)), (t2.c1 % 3)
Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
(7 rows)
@@ -2651,10 +2651,10 @@ select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
- Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ Output: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST), (t2.c1 % 3)
+ Sort Key: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)
-> Foreign Scan
- Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Output: array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST), (t2.c1 % 3)
Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
(7 rows)
@@ -2672,10 +2672,10 @@ select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------
Sort
- Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
- Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ Output: sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5))), c2
+ Sort Key: sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5)))
-> Foreign Scan
- Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Output: sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5))), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
(7 rows)
@@ -2701,7 +2701,7 @@ select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 f
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
- Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Output: sum((c1 % 3)), sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2)), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
(4 rows)
@@ -2718,17 +2718,17 @@ select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft
QUERY PLAN
-------------------------------------------------------------------------------------------------------
Unique
- Output: ((SubPlan 1))
+ Output: (SubPlan 1)
-> Sort
- Output: ((SubPlan 1))
- Sort Key: ((SubPlan 1))
+ Output: (SubPlan 1)
+ Sort Key: (SubPlan 1)
-> Foreign Scan
Output: (SubPlan 1)
Relations: Aggregate on (public.ft2 t2)
Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
SubPlan 1
-> Foreign Scan on public.ft1 t1
- Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Output: count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10)))
Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
(13 rows)
@@ -2744,16 +2744,16 @@ select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) fro
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------
Unique
- Output: ((SubPlan 1))
+ Output: (SubPlan 1)
-> Sort
- Output: ((SubPlan 1))
- Sort Key: ((SubPlan 1))
+ Output: (SubPlan 1)
+ Sort Key: (SubPlan 1)
-> Foreign Scan on public.ft2 t2
Output: (SubPlan 1)
Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
SubPlan 1
-> Foreign Scan
- Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Output: count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10)))
Relations: Aggregate on (public.ft1 t1)
Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
(13 rows)
@@ -2802,10 +2802,10 @@ select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Output: c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6), percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision))
Sort Key: ft1.c2
-> Foreign Scan
- Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Output: c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6), percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision))
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
(7 rows)
@@ -2826,7 +2826,7 @@ select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
- Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Output: c1, rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2), c2
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY "C 1", c2
(4 rows)
@@ -2870,10 +2870,10 @@ select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------
Sort
- Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
Sort Key: ft1.c2
-> Foreign Scan
- Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
(7 rows)
@@ -2972,7 +2972,7 @@ select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan
- Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
Relations: Aggregate on (public.ft2)
Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
(4 rows)
@@ -3052,7 +3052,7 @@ select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x w
-> Subquery Scan on x
Output: x.b, x.a
-> Foreign Scan
- Output: ft1_1.c2, (sum(ft1_1.c1))
+ Output: ft1_1.c2, sum(ft1_1.c1)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
(20 rows)
@@ -3078,10 +3078,10 @@ select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) gr
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Sort
- Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
- Sort Key: (avg(t1.c1)), (sum(t2.c1))
+ Output: avg(t1.c1), sum(t2.c1), t2.c1
+ Sort Key: avg(t1.c1), sum(t2.c1)
-> Foreign Scan
- Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Output: avg(t1.c1), sum(t2.c1), t2.c1
Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
(7 rows)
@@ -3098,13 +3098,13 @@ select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) gr
-- foreign server.
explain (verbose, costs off)
select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
- QUERY PLAN
---------------------------------------------------------------------------------
+ QUERY PLAN
+----------------------------------------------------------------------------
Sort
- Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
- Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ Output: (sum(c2) * ((random() <= '1'::double precision))::integer)
+ Sort Key: (sum(ft1.c2) * ((random() <= '1'::double precision))::integer)
-> Foreign Scan
- Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Output: (sum(c2) * ((random() <= '1'::double precision))::integer)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
(7 rows)
@@ -3133,7 +3133,7 @@ select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum fr
Output: qry.sum, t2.c1
Filter: ((t1.c2 * 2) = qry.sum)
-> Foreign Scan
- Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Output: sum((t2.c1 + t1."C 1")), t2.c1
Relations: Aggregate on (public.ft2 t2)
Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
(15 rows)
@@ -3178,7 +3178,7 @@ select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.
-> Subquery Scan on q
Output: q.b, q.a
-> Foreign Scan
- Output: (min(13)), (avg(ft1.c1)), (NULL::bigint)
+ Output: min(13), avg(ft1.c1), NULL::bigint
Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
Remote SQL: SELECT min(13), avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
(23 rows)
@@ -3293,12 +3293,12 @@ select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
QUERY PLAN
--------------------------------------------------------------------------------------------------------
Unique
- Output: ((sum(c1) / 1000)), c2
+ Output: (sum(c1) / 1000), c2
-> Sort
- Output: ((sum(c1) / 1000)), c2
- Sort Key: ((sum(ft2.c1) / 1000))
+ Output: (sum(c1) / 1000), c2
+ Sort Key: (sum(ft2.c1) / 1000)
-> Foreign Scan
- Output: ((sum(c1) / 1000)), c2
+ Output: (sum(c1) / 1000), c2
Relations: Aggregate on (public.ft2)
Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
(9 rows)
@@ -3316,15 +3316,15 @@ select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 gr
QUERY PLAN
-------------------------------------------------------------------------------------------------------------
Sort
- Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Output: c2, sum(c2), (count(c2) OVER (?)), (c2 % 2)
Sort Key: ft2.c2
-> WindowAgg
- Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ Output: c2, sum(c2), count(c2) OVER (?), (c2 % 2)
-> Sort
- Output: c2, ((c2 % 2)), (sum(c2))
- Sort Key: ((ft2.c2 % 2))
+ Output: c2, (c2 % 2), sum(c2)
+ Sort Key: (ft2.c2 % 2)
-> Foreign Scan
- Output: c2, ((c2 % 2)), (sum(c2))
+ Output: c2, (c2 % 2), sum(c2)
Relations: Aggregate on (public.ft2)
Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
(12 rows)
@@ -3349,15 +3349,15 @@ select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 wher
QUERY PLAN
----------------------------------------------------------------------------------------------------
Sort
- Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Output: c2, (array_agg(c2) OVER (?)), (c2 % 2)
Sort Key: ft1.c2
-> WindowAgg
- Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ Output: c2, array_agg(c2) OVER (?), (c2 % 2)
-> Sort
- Output: c2, ((c2 % 2))
- Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ Output: c2, (c2 % 2)
+ Sort Key: (ft1.c2 % 2), ft1.c2 DESC
-> Foreign Scan
- Output: c2, ((c2 % 2))
+ Output: c2, (c2 % 2)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
(12 rows)
@@ -3382,15 +3382,15 @@ select c2, array_agg(c2) over (partition by c2%2 order by c2 range between curre
QUERY PLAN
----------------------------------------------------------------------------------------------------
Sort
- Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Output: c2, (array_agg(c2) OVER (?)), (c2 % 2)
Sort Key: ft1.c2
-> WindowAgg
- Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ Output: c2, array_agg(c2) OVER (?), (c2 % 2)
-> Sort
- Output: c2, ((c2 % 2))
- Sort Key: ((ft1.c2 % 2)), ft1.c2
+ Output: c2, (c2 % 2)
+ Sort Key: (ft1.c2 % 2), ft1.c2
-> Foreign Scan
- Output: c2, ((c2 % 2))
+ Output: c2, (c2 % 2)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
(12 rows)
@@ -3645,7 +3645,7 @@ SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
QUERY PLAN
-------------------------------------------------------------------------------
Limit
- Output: ((tableoid)::regclass), c1, c2, c3, c4, c5, c6, c7, c8
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
-> Foreign Scan on public.ft1 t1
Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
@@ -3901,7 +3901,7 @@ INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
-> Subquery Scan on "*SELECT*"
Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
-> Limit
- Output: ((ft2_1.c1 + 1000)), ((ft2_1.c2 + 100)), ((ft2_1.c3 || ft2_1.c3))
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
-> Foreign Scan on public.ft2 ft2_1
Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
@@ -5575,7 +5575,7 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
QUERY PLAN
-----------------------------------------------------------------
Foreign Scan
- Output: (count(*))
+ Output: count(*)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
@@ -5619,7 +5619,7 @@ EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
QUERY PLAN
------------------------------------------------------------------
Foreign Scan
- Output: (count(*))
+ Output: count(*)
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 8a81d7a..8628b18 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -6037,7 +6037,7 @@ get_variable(Var *var, int levelsup, bool istoplevel, deparse_context *context)
}
else
{
- resolve_special_varno((Node *) var, context, NULL,
+ resolve_special_varno((Node *) var, context, dpns,
get_special_variable);
return NULL;
}
@@ -6168,15 +6168,17 @@ static void
get_special_variable(Node *node, deparse_context *context, void *private)
{
StringInfo buf = context->buf;
+ deparse_namespace *dpns = (deparse_namespace *) private;
/*
* Force parentheses because our caller probably assumed a Var is a simple
- * expression.
+ * expression. However if underneath PlanState is ForeignScanState, then
+ * don't force parentheses.
*/
- if (!IsA(node, Var))
+ if (!IsA(node, Var) && !IsA(dpns->planstate, ForeignScanState))
appendStringInfoChar(buf, '(');
get_rule_expr(node, context, true);
- if (!IsA(node, Var))
+ if (!IsA(node, Var) && !IsA(dpns->planstate, ForeignScanState))
appendStringInfoChar(buf, ')');
}
The patch compiles and make check-world doesn't show any failures.
ExecInitForeignScan() while determining scan tuple type from passed
fdw_scan_tlist, has target list containing Vars with varno set to
INDEX_VAR. Due to which while deparsing we go through
resolve_special_varno() and get_special_variable() function which
forces parenthesis around the expression.
I can't think of any easy and quick solution here. So keeping this
as is. Input will be welcome or this can be done separately later.I guess, you can decide whether or not to add paranthesis by looking
at the corresponding namespace in the deparse_context. If the
planstate there is ForeignScanState, you may skip the paranthesis if
istoplevel is true. Can you please check if this works?I have tried it. Attached separate patch for it.
However I have noticed that istoplevel is always false (at-least for the
testcase we have, I get it false always). And I also think that taking
this decision only on PlanState is enough. Does that in attached patch.
To fix this, I have passed deparse_namespace to the private argument and
accessed it in get_special_variable(). Changes looks very simple. Please
have a look and let me know your views.
This issue is not introduced by the changes done for the aggregate push
down, it only got exposed as we now ship expressions in the target list.
Thus I think it will be good if we make these changes separately as new
patch, if required.
The patch looks good and pretty simple.
+ * expression. However if underneath PlanState is ForeignScanState, then
+ * don't force parentheses.
We need to explain why it's safe not to add paranthesis. The reason
this function adds paranthesis so as to preserve any operator
precedences imposed by the expression tree of which this IndexVar is
part. For ForeignScanState, the Var may represent the root of the
expression tree, and thus not need paranthesis. But we need to verify
this and explain it in the comments.
As you have explained this is an issue exposed by this patch;
something not must have in this patch. If committers feel that
aggregate pushdown needs this fix as well, please provide a patch
addressing the above comment.
Moved testcases after Join testcases.
However I have not made any capitalization changes. I see many tests
like those elsewhere in the file too. Let me know if that's the policy
to have appropriate capitalization in test-case. I don't want violate
the policy if any and will prefer to do the changes as per the policy.This file has used different styles for different sets. But we usually
adopt the style from surrounding testcases. The testcases surrounding
aggregate testcase block are capitalized. It will look odd to have
just the aggregate tests using different style.I see mixed use of capitalization in the file and use of it is adhoc too.
So not convinced with your argument yet. I don't think there is any policy
for that; otherwise use of capitalization in this file would have been
consistent already. Can we defer this to the committer's opinion.
Ok. PFA patch with cosmetic changes (mostly rewording comments). Let
me know if those look good. I am marking this patch is ready for
committer.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
Attachments:
pg_agg_push_down_v5.patchbinary/octet-stream; name=pg_agg_push_down_v5.patchDownload
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 691658f..6a9dffc 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -38,6 +38,7 @@
#include "access/heapam.h"
#include "access/htup_details.h"
#include "access/sysattr.h"
+#include "catalog/pg_aggregate.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_namespace.h"
#include "catalog/pg_operator.h"
@@ -56,6 +57,7 @@
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
/*
@@ -65,6 +67,8 @@ typedef struct foreign_glob_cxt
{
PlannerInfo *root; /* global planner state */
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ Relids relids; /* relids of base relations in the underlying
+ scan */
} foreign_glob_cxt;
/*
@@ -94,6 +98,9 @@ typedef struct deparse_expr_cxt
{
PlannerInfo *root; /* global planner state */
RelOptInfo *foreignrel; /* the foreign relation we are planning for */
+ RelOptInfo *scanrel; /* the underlying scan relation. Same as
+ foreignrel, when that represents a join or
+ a base relation. */
StringInfo buf; /* output buffer to append to */
List **params_list; /* exprs that will become remote Params */
} deparse_expr_cxt;
@@ -135,7 +142,7 @@ static void deparseColumnRef(StringInfo buf, int varno, int varattno,
static void deparseRelation(StringInfo buf, Relation rel);
static void deparseExpr(Expr *expr, deparse_expr_cxt *context);
static void deparseVar(Var *node, deparse_expr_cxt *context);
-static void deparseConst(Const *node, deparse_expr_cxt *context);
+static void deparseConst(Const *node, deparse_expr_cxt *context, int showtype);
static void deparseParam(Param *node, deparse_expr_cxt *context);
static void deparseArrayRef(ArrayRef *node, deparse_expr_cxt *context);
static void deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context);
@@ -159,6 +166,14 @@ static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context);
static void appendConditions(List *exprs, deparse_expr_cxt *context);
static void deparseFromExprForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *joinrel, bool use_alias, List **params_list);
+static void deparseFromExpr(List *quals, deparse_expr_cxt *context);
+static void deparseAggref(Aggref *node, deparse_expr_cxt *context);
+static void appendGroupByClause(List *tlist, deparse_expr_cxt *context);
+static void appendAggOrderBy(List *orderList, List *targetList,
+ deparse_expr_cxt *context);
+static void appendFunctionName(Oid funcid, deparse_expr_cxt *context);
+static Node *deparseSortGroupClause(Index ref, List *tlist,
+ deparse_expr_cxt *context);
/*
@@ -200,6 +215,7 @@ is_foreign_expr(PlannerInfo *root,
{
foreign_glob_cxt glob_cxt;
foreign_loc_cxt loc_cxt;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) (baserel->fdw_private);
/*
* Check that the expression consists of nodes that are safe to execute
@@ -207,6 +223,14 @@ is_foreign_expr(PlannerInfo *root,
*/
glob_cxt.root = root;
glob_cxt.foreignrel = baserel;
+ /*
+ * For an upper relation, use relids from its underneath scan relation.
+ * For other relation, use their own relids.
+ */
+ if (baserel->reloptkind == RELOPT_UPPER_REL)
+ glob_cxt.relids = fpinfo->outerrel->relids;
+ else
+ glob_cxt.relids = baserel->relids;
loc_cxt.collation = InvalidOid;
loc_cxt.state = FDW_COLLATE_NONE;
if (!foreign_expr_walker((Node *) expr, &glob_cxt, &loc_cxt))
@@ -281,7 +305,7 @@ foreign_expr_walker(Node *node,
* Param's collation, ie it's not safe for it to have a
* non-default collation.
*/
- if (bms_is_member(var->varno, glob_cxt->foreignrel->relids) &&
+ if (bms_is_member(var->varno, glob_cxt->relids) &&
var->varlevelsup == 0)
{
/* Var belongs to foreign table */
@@ -631,6 +655,109 @@ foreign_expr_walker(Node *node,
check_type = false;
}
break;
+ case T_Aggref:
+ {
+ Aggref *agg = (Aggref *) node;
+ ListCell *lc;
+
+ /* Not safe to pushdown when not in grouping context */
+ if (glob_cxt->foreignrel->reloptkind != RELOPT_UPPER_REL)
+ return false;
+
+ /* Only non-split aggregates are pushable. */
+ if (agg->aggsplit != AGGSPLIT_SIMPLE)
+ return false;
+
+ /*
+ * If aggregate function used by the expression is not
+ * shippable, it can't be sent to remote because it might
+ * have incompatible semantics on remote side.
+ */
+ if (!is_shippable(agg->aggfnoid, ProcedureRelationId, fpinfo))
+ return false;
+
+ /*
+ * Recurse to input args. aggdirectargs, aggorder and
+ * aggdistinct are all present in args, so no need to
+ * check their shippability explicitly.
+ */
+ foreach(lc, agg->args)
+ {
+ Node *n = (Node *) lfirst(lc);
+
+ /* If TargetEntry, extract the expression from it */
+ if (IsA(n, TargetEntry))
+ {
+ TargetEntry *tle = (TargetEntry *) n;
+ n = (Node *) tle->expr;
+ }
+
+ if (!foreign_expr_walker(n, glob_cxt, &inner_cxt))
+ return false;
+ }
+
+ /*
+ * For aggorder elements, check whether the sort operator, if
+ * specified, is shippable or not.
+ */
+ if (agg->aggorder)
+ {
+ ListCell *lc;
+
+ foreach (lc, agg->aggorder)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+ TargetEntry *tle;
+
+ tle = get_sortgroupref_tle(srt->tleSortGroupRef,
+ agg->args);
+ sortcoltype = exprType((Node *) tle->expr);
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ /* Check shippability of non-default sort operator. */
+ if (srt->sortop != typentry->lt_opr &&
+ srt->sortop != typentry->gt_opr)
+ if (!is_shippable(srt->sortop, OperatorRelationId,
+ fpinfo))
+ return false;
+ }
+ }
+
+ /* Check aggregate filter */
+ if (!foreign_expr_walker((Node *) agg->aggfilter,
+ glob_cxt, &inner_cxt))
+ return false;
+
+ /*
+ * If aggregate's input collation is not derived from a foreign
+ * Var, it can't be sent to remote.
+ */
+ if (agg->inputcollid == InvalidOid)
+ /* OK, inputs are all noncollatable */ ;
+ else if (inner_cxt.state != FDW_COLLATE_SAFE ||
+ agg->inputcollid != inner_cxt.collation)
+ return false;
+
+ /*
+ * Detect whether node is introducing a collation not derived
+ * from a foreign Var. (If so, we just mark it unsafe for now
+ * rather than immediately returning false, since the parent
+ * node might not care.)
+ */
+ collation = agg->aggcollid;
+ if (collation == InvalidOid)
+ state = FDW_COLLATE_NONE;
+ else if (inner_cxt.state == FDW_COLLATE_SAFE &&
+ collation == inner_cxt.collation)
+ state = FDW_COLLATE_SAFE;
+ else if (collation == DEFAULT_COLLATION_OID)
+ state = FDW_COLLATE_NONE;
+ else
+ state = FDW_COLLATE_UNSAFE;
+ }
+ break;
default:
/*
@@ -720,7 +847,9 @@ deparse_type_name(Oid type_oid, int32 typemod)
* Build the targetlist for given relation to be deparsed as SELECT clause.
*
* The output targetlist contains the columns that need to be fetched from the
- * foreign server for the given relation.
+ * foreign server for the given relation. If foreignrel is an upper relation,
+ * then the output targetlist can also contains expressions to be evaluated on
+ * foreign server.
*/
List *
build_tlist_to_deparse(RelOptInfo *foreignrel)
@@ -729,6 +858,13 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private;
/*
+ * For an upper relation, we have already built the target list while
+ * checking shippability, return that.
+ */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ return fpinfo->grouped_tlist;
+
+ /*
* We require columns specified in foreignrel->reltarget->exprs and those
* required for evaluating the local conditions.
*/
@@ -750,6 +886,7 @@ build_tlist_to_deparse(RelOptInfo *foreignrel)
* hence the tlist is ignored for a base relation.
*
* remote_conds is the list of conditions to be deparsed as WHERE clause.
+ * However for upper relation it is deparsed as HAVING clause.
*
* If params_list is not NULL, it receives a list of Params and other-relation
* Vars used in the clauses; these values must be transmitted to the remote
@@ -768,28 +905,56 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
List **retrieved_attrs, List **params_list)
{
deparse_expr_cxt context;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *)rel->fdw_private;
+ List *quals;
- /* We handle relations for foreign tables and joins between those */
+ /*
+ * We handle relations for foreign tables, joins between those and upper
+ * relations.
+ */
Assert(rel->reloptkind == RELOPT_JOINREL ||
rel->reloptkind == RELOPT_BASEREL ||
- rel->reloptkind == RELOPT_OTHER_MEMBER_REL);
+ rel->reloptkind == RELOPT_OTHER_MEMBER_REL ||
+ rel->reloptkind == RELOPT_UPPER_REL);
- /* Fill portions of context common to join and base relation */
+ /* Fill portions of context common to upper, join and base relation */
context.buf = buf;
context.root = root;
context.foreignrel = rel;
+ context.scanrel = (rel->reloptkind == RELOPT_UPPER_REL) ? fpinfo->outerrel : rel;
context.params_list = params_list;
- /* Construct SELECT clause and FROM clause */
+ /* Construct SELECT clause */
deparseSelectSql(tlist, retrieved_attrs, &context);
/*
- * Construct WHERE clause
+ * For upper relations, WHERE clause is built from the underneath scan
+ * relation's remote conditions.
*/
- if (remote_conds)
+ if (rel->reloptkind == RELOPT_UPPER_REL)
{
- appendStringInfo(buf, " WHERE ");
- appendConditions(remote_conds, &context);
+ PgFdwRelationInfo *ofpinfo;
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+ quals = ofpinfo->remote_conds;
+ }
+ else
+ quals = remote_conds;
+
+ /* Construct FROM and WHERE clauses */
+ deparseFromExpr(quals, &context);
+
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ {
+ /* Append GROUP BY clause */
+ appendGroupByClause(tlist, &context);
+
+ /* Append HAVING clause */
+ if (remote_conds)
+ {
+ appendStringInfo(buf, " HAVING ");
+ appendConditions(remote_conds, &context);
+ }
}
/* Add ORDER BY clause if we found any useful pathkeys */
@@ -803,7 +968,7 @@ deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel,
/*
* Construct a simple SELECT statement that retrieves desired columns
* of the specified foreign table, and append it to "buf". The output
- * contains just "SELECT ... FROM ....".
+ * contains just "SELECT ... ".
*
* We also create an integer List of the columns being retrieved, which is
* returned to *retrieved_attrs.
@@ -824,7 +989,8 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
*/
appendStringInfoString(buf, "SELECT ");
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation use the input tlist */
deparseExplicitTargetList(tlist, retrieved_attrs, context);
@@ -847,14 +1013,39 @@ deparseSelectSql(List *tlist, List **retrieved_attrs, deparse_expr_cxt *context)
fpinfo->attrs_used, false, retrieved_attrs);
heap_close(rel, NoLock);
}
+}
- /*
- * Construct FROM clause
- */
+/*
+ * Construct a FROM clause and a WHERE clause, if any, and append those to
+ * "buf".
+ *
+ * quals is the list of clauses to be included in the WHERE clause,
+ * NIL if none.
+ */
+static void
+deparseFromExpr(List *quals, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ RelOptInfo *foreignrel = context->foreignrel;
+ RelOptInfo *scanrel = context->scanrel;
+
+ /* For upper relations, scanrel must be either a joinrel or a baserel */
+ if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ Assert(scanrel->reloptkind == RELOPT_JOINREL ||
+ scanrel->reloptkind == RELOPT_BASEREL);
+
+ /* Construct FROM clause */
appendStringInfoString(buf, " FROM ");
- deparseFromExprForRel(buf, root, foreignrel,
- (foreignrel->reloptkind == RELOPT_JOINREL),
+ deparseFromExprForRel(buf, context->root, scanrel,
+ (bms_num_members(scanrel->relids) > 1),
context->params_list);
+
+ /* Construct WHERE clause */
+ if (quals)
+ {
+ appendStringInfo(buf, " WHERE ");
+ appendConditions(quals, context);
+ }
}
/*
@@ -957,14 +1148,14 @@ deparseTargetList(StringInfo buf,
/*
* Deparse the appropriate locking clause (FOR UPDATE or FOR SHARE) for a
- * given relation (context->foreignrel).
+ * given relation (context->scanrel).
*/
static void
deparseLockingClause(deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
PlannerInfo *root = context->root;
- RelOptInfo *rel = context->foreignrel;
+ RelOptInfo *rel = context->scanrel;
int relid = -1;
while ((relid = bms_next_member(rel->relids, relid)) >= 0)
@@ -1024,7 +1215,7 @@ deparseLockingClause(deparse_expr_cxt *context)
}
/* Add the relation alias if we are here for a join relation */
- if (rel->reloptkind == RELOPT_JOINREL &&
+ if (bms_num_members(rel->relids) > 1 &&
rc->strength != LCS_NONE)
appendStringInfo(buf, " OF %s%d", REL_ALIAS_PREFIX, relid);
}
@@ -1036,7 +1227,7 @@ deparseLockingClause(deparse_expr_cxt *context)
* Deparse conditions from the provided list and append them to buf.
*
* The conditions in the list are assumed to be ANDed. This function is used to
- * deparse both WHERE clauses and JOIN .. ON clauses.
+ * deparse WHERE clauses, JOIN .. ON clauses and HAVING clauses.
*/
static void
appendConditions(List *exprs, deparse_expr_cxt *context)
@@ -1126,22 +1317,15 @@ deparseExplicitTargetList(List *tlist, List **retrieved_attrs,
foreach(lc, tlist)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
- Var *var;
/* Extract expression if TargetEntry node */
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
-
- /* We expect only Var nodes here */
- if (!IsA(var, Var))
- elog(ERROR, "non-Var not expected in target list");
if (i > 0)
appendStringInfoString(buf, ", ");
- deparseVar(var, context);
+ deparseExpr((Expr *) tle->expr, context);
*retrieved_attrs = lappend_int(*retrieved_attrs, i + 1);
-
i++;
}
@@ -1192,6 +1376,7 @@ deparseFromExprForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
context.buf = buf;
context.foreignrel = foreignrel;
+ context.scanrel = foreignrel;
context.root = root;
context.params_list = params_list;
@@ -1360,6 +1545,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1444,6 +1630,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
/* Set up context struct for recursion */
context.root = root;
context.foreignrel = baserel;
+ context.scanrel = baserel;
context.buf = buf;
context.params_list = params_list;
@@ -1817,7 +2004,7 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
deparseVar((Var *) node, context);
break;
case T_Const:
- deparseConst((Const *) node, context);
+ deparseConst((Const *) node, context, 0);
break;
case T_Param:
deparseParam((Param *) node, context);
@@ -1849,6 +2036,9 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
case T_ArrayExpr:
deparseArrayExpr((ArrayExpr *) node, context);
break;
+ case T_Aggref:
+ deparseAggref((Aggref *)node, context);
+ break;
default:
elog(ERROR, "unsupported expression type for deparse: %d",
(int) nodeTag(node));
@@ -1867,10 +2057,11 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
static void
deparseVar(Var *node, deparse_expr_cxt *context)
{
- bool qualify_col = (context->foreignrel->reloptkind == RELOPT_JOINREL);
+ Relids relids = context->scanrel->relids;
+ /* Qualify columns when multiple relations are involved. */
+ bool qualify_col = (bms_num_members(relids) > 1) ? true : false;
- if (bms_is_member(node->varno, context->foreignrel->relids) &&
- node->varlevelsup == 0)
+ if (bms_is_member(node->varno, relids) && node->varlevelsup == 0)
deparseColumnRef(context->buf, node->varno, node->varattno,
context->root, qualify_col);
else
@@ -1910,7 +2101,7 @@ deparseVar(Var *node, deparse_expr_cxt *context)
* This function has to be kept in sync with ruleutils.c's get_const_expr.
*/
static void
-deparseConst(Const *node, deparse_expr_cxt *context)
+deparseConst(Const *node, deparse_expr_cxt *context, int showtype)
{
StringInfo buf = context->buf;
Oid typoutput;
@@ -1922,9 +2113,10 @@ deparseConst(Const *node, deparse_expr_cxt *context)
if (node->constisnull)
{
appendStringInfoString(buf, "NULL");
- appendStringInfo(buf, "::%s",
- deparse_type_name(node->consttype,
- node->consttypmod));
+ if (showtype >= 0)
+ appendStringInfo(buf, "::%s",
+ deparse_type_name(node->consttype,
+ node->consttypmod));
return;
}
@@ -1974,9 +2166,14 @@ deparseConst(Const *node, deparse_expr_cxt *context)
break;
}
+ pfree(extval);
+
+ if (showtype < 0)
+ return;
+
/*
- * Append ::typename unless the constant will be implicitly typed as the
- * right type when it is read in.
+ * For showtype == 0, append ::typename unless the constant will be
+ * implicitly typed as the right type when it is read in.
*
* XXX this code has to be kept in sync with the behavior of the parser,
* especially make_const.
@@ -1995,7 +2192,7 @@ deparseConst(Const *node, deparse_expr_cxt *context)
needlabel = true;
break;
}
- if (needlabel)
+ if (needlabel || showtype > 0)
appendStringInfo(buf, "::%s",
deparse_type_name(node->consttype,
node->consttypmod));
@@ -2092,9 +2289,6 @@ static void
deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
{
StringInfo buf = context->buf;
- HeapTuple proctup;
- Form_pg_proc procform;
- const char *proname;
bool use_variadic;
bool first;
ListCell *arg;
@@ -2127,29 +2321,15 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
return;
}
- /*
- * Normal function: display as proname(args).
- */
- proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->funcid));
- if (!HeapTupleIsValid(proctup))
- elog(ERROR, "cache lookup failed for function %u", node->funcid);
- procform = (Form_pg_proc) GETSTRUCT(proctup);
-
/* Check if need to print VARIADIC (cf. ruleutils.c) */
use_variadic = node->funcvariadic;
- /* Print schema name only if it's not pg_catalog */
- if (procform->pronamespace != PG_CATALOG_NAMESPACE)
- {
- const char *schemaname;
-
- schemaname = get_namespace_name(procform->pronamespace);
- appendStringInfo(buf, "%s.", quote_identifier(schemaname));
- }
+ /*
+ * Normal function: display as proname(args).
+ */
+ appendFunctionName(node->funcid, context);
+ appendStringInfoChar(buf, '(');
- /* Deparse the function name ... */
- proname = NameStr(procform->proname);
- appendStringInfo(buf, "%s(", quote_identifier(proname));
/* ... and all the arguments */
first = true;
foreach(arg, node->args)
@@ -2162,8 +2342,6 @@ deparseFuncExpr(FuncExpr *node, deparse_expr_cxt *context)
first = false;
}
appendStringInfoChar(buf, ')');
-
- ReleaseSysCache(proctup);
}
/*
@@ -2420,6 +2598,152 @@ deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context)
}
/*
+ * Deparse an Aggref node.
+ */
+static void
+deparseAggref(Aggref *node, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ bool use_variadic;
+
+ /* Only basic, non-split aggregation accepted. */
+ Assert(node->aggsplit == AGGSPLIT_SIMPLE);
+
+ /* Check if need to print VARIADIC (cf. ruleutils.c) */
+ use_variadic = node->aggvariadic;
+
+ /* Find aggregate name from aggfnoid which is a pg_proc entry */
+ appendFunctionName(node->aggfnoid, context);
+ appendStringInfoChar(buf, '(');
+
+ /* Add DISTINCT */
+ appendStringInfo(buf, "%s", (node->aggdistinct != NIL) ? "DISTINCT " : "");
+
+ if (AGGKIND_IS_ORDERED_SET(node->aggkind))
+ {
+ /* Add WITHIN GROUP (ORDER BY ..) */
+ ListCell *arg;
+ bool first = true;
+
+ Assert(!node->aggvariadic);
+ Assert(node->aggorder != NIL);
+
+ foreach(arg, node->aggdirectargs)
+ {
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseExpr((Expr *) lfirst(arg), context);
+ }
+
+ appendStringInfoString(buf, ") WITHIN GROUP (ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ else
+ {
+ /* aggstar can be set only in zero-argument aggregates */
+ if (node->aggstar)
+ appendStringInfoChar(buf, '*');
+ else
+ {
+ ListCell *arg;
+ bool first = true;
+
+ /* ... and all the arguments */
+ foreach(arg, node->args)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(arg);
+ Node *n = (Node *) tle->expr;
+
+ if (tle->resjunk)
+ continue;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ /* Add VARIADIC */
+ if (use_variadic && lnext(arg) == NULL)
+ appendStringInfoString(buf, "VARIADIC ");
+
+ deparseExpr((Expr *) n, context);
+ }
+ }
+
+ /* Add ORDER BY */
+ if (node->aggorder != NIL)
+ {
+ appendStringInfoString(buf, " ORDER BY ");
+ appendAggOrderBy(node->aggorder, node->args, context);
+ }
+ }
+
+ /* Add FILTER (WHERE ..) */
+ if (node->aggfilter != NULL)
+ {
+ appendStringInfoString(buf, ") FILTER (WHERE ");
+ deparseExpr((Expr *) node->aggfilter, context);
+ }
+
+ appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Append ORDER BY within aggregate function.
+ */
+static void
+appendAggOrderBy(List *orderList, List *targetList, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ ListCell *lc;
+ bool first = true;
+
+ foreach (lc, orderList)
+ {
+ SortGroupClause *srt = (SortGroupClause *) lfirst(lc);
+ Node *sortexpr;
+ Oid sortcoltype;
+ TypeCacheEntry *typentry;
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ sortexpr = deparseSortGroupClause(srt->tleSortGroupRef, targetList,
+ context);
+ sortcoltype = exprType(sortexpr);
+ /* See whether operator is default < or > for datatype */
+ typentry = lookup_type_cache(sortcoltype,
+ TYPECACHE_LT_OPR | TYPECACHE_GT_OPR);
+ if (srt->sortop == typentry->lt_opr)
+ appendStringInfoString(buf, " ASC");
+ else if (srt->sortop == typentry->gt_opr)
+ appendStringInfoString(buf, " DESC");
+ else
+ {
+ HeapTuple opertup;
+ Form_pg_operator operform;
+
+ appendStringInfoString(buf, " USING ");
+
+ /* Append operator name. */
+ opertup = SearchSysCache1(OPEROID, ObjectIdGetDatum(srt->sortop));
+ if (!HeapTupleIsValid(opertup))
+ elog(ERROR, "cache lookup failed for operator %u", srt->sortop);
+ operform = (Form_pg_operator) GETSTRUCT(opertup);
+ deparseOperatorName(buf, operform);
+ ReleaseSysCache(opertup);
+ }
+
+ if (srt->nulls_first)
+ appendStringInfoString(buf, " NULLS FIRST");
+ else
+ appendStringInfoString(buf, " NULLS LAST");
+ }
+}
+
+/*
* Print the representation of a parameter to be sent to the remote side.
*
* Note: we always label the Param's type explicitly rather than relying on
@@ -2464,6 +2788,41 @@ printRemotePlaceholder(Oid paramtype, int32 paramtypmod,
}
/*
+ * Deparse GROUP BY clause.
+ */
+static void
+appendGroupByClause(List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ Query *query = context->root->parse;
+ ListCell *lc;
+ bool first = true;
+
+ /* Nothing to be done, if there's no GROUP BY clause in the query. */
+ if (!query->groupClause)
+ return;
+
+ appendStringInfo(buf, " GROUP BY ");
+
+ /*
+ * Queries with grouping sets are not pushed down, so we don't expect
+ * grouping sets here.
+ */
+ Assert(!query->groupingSets);
+
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *grp = (SortGroupClause *) lfirst(lc);
+
+ if (!first)
+ appendStringInfoString(buf, ", ");
+ first = false;
+
+ deparseSortGroupClause(grp->tleSortGroupRef, tlist, context);
+ }
+}
+
+/*
* Deparse ORDER BY clause according to the given pathkeys for given base
* relation. From given pathkeys expressions belonging entirely to the given
* base relation are obtained and deparsed.
@@ -2474,7 +2833,7 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
ListCell *lcell;
int nestlevel;
char *delim = " ";
- RelOptInfo *baserel = context->foreignrel;
+ RelOptInfo *baserel = context->scanrel;
StringInfo buf = context->buf;
/* Make sure any constants in the exprs are printed portably */
@@ -2505,3 +2864,67 @@ appendOrderByClause(List *pathkeys, deparse_expr_cxt *context)
}
reset_transmission_modes(nestlevel);
}
+
+/*
+ * appendFunctionName
+ * Deparses function name from given function oid.
+ */
+static void
+appendFunctionName(Oid funcid, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ HeapTuple proctup;
+ Form_pg_proc procform;
+ const char *proname;
+
+ proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(funcid));
+ if (!HeapTupleIsValid(proctup))
+ elog(ERROR, "cache lookup failed for function %u", funcid);
+ procform = (Form_pg_proc) GETSTRUCT(proctup);
+
+ /* Print schema name only if it's not pg_catalog */
+ if (procform->pronamespace != PG_CATALOG_NAMESPACE)
+ {
+ const char *schemaname;
+
+ schemaname = get_namespace_name(procform->pronamespace);
+ appendStringInfo(buf, "%s.", quote_identifier(schemaname));
+ }
+
+ /* Deparse the function name ... */
+ proname = NameStr(procform->proname);
+ appendStringInfo(buf, "%s", quote_identifier(proname));
+
+ ReleaseSysCache(proctup);
+}
+
+/*
+ * Appends a sort or group clause.
+ *
+ * Like get_rule_sortgroupclause(), returns the expression tree, so caller
+ * need not find it again.
+ */
+static Node *
+deparseSortGroupClause(Index ref, List *tlist, deparse_expr_cxt *context)
+{
+ StringInfo buf = context->buf;
+ TargetEntry *tle;
+ Expr *expr;
+
+ tle = get_sortgroupref_tle(ref, tlist);
+ expr = tle->expr;
+
+ if (expr && IsA(expr, Const))
+ deparseConst((Const *) expr, context, 1);
+ else if (!expr || IsA(expr, Var))
+ deparseExpr(expr, context);
+ else
+ {
+ /* Always parenthesize the expression. */
+ appendStringInfoString(buf, "(");
+ deparseExpr(expr, context);
+ appendStringInfoString(buf, ")");
+ }
+
+ return (Node *) expr;
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d97e694..d3f37ad 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -861,14 +861,13 @@ CREATE OPERATOR === (
-- built-in operators and functions can be shipped for remote execution
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
- QUERY PLAN
---------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
-(5 rows)
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
count
@@ -878,14 +877,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
- QUERY PLAN
----------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = c2))
-(5 rows)
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
count
@@ -937,14 +935,13 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
-- ... now they can be shipped
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
- QUERY PLAN
-----------------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
count
@@ -954,14 +951,13 @@ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
EXPLAIN (VERBOSE, COSTS OFF)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
- QUERY PLAN
-----------------------------------------------------------------------------------------
- Aggregate
- Output: count(c3)
- -> Foreign Scan on public.ft1 t1
- Output: c3
- Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
-(5 rows)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
count
@@ -2283,6 +2279,1138 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Result
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ -> Sort
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Sort Key: (count(ft1.c6)), (sum(ft1.c1))
+ -> Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY c2
+(9 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Sort Key: ((ft1.c2 / 2))
+ -> Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY ((c2 / 2))
+(7 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Sort
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Sort Key: ft1.c2, (sum(ft1.c1))
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY c2, (sqrt("C 1"))
+(9 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, (5), (7.0), (9)
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, (5), (7.0), (9)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY c2, 5::integer, 9::integer
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft2.c2
+ -> Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800))
+(7 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Sort Key: ft1.c5, (count(ft1.c2))
+ -> Foreign Scan
+ Output: c5, (count(c2)), (sqrt((c2)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, count(c2), sqrt(c2) FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((sqrt(max(c2)) = 1.41421356237309515::double precision))
+(7 rows)
+
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+ c5 | count
+--------------------------+-------
+ Sat Jan 03 00:00:00 1970 | 10
+ Tue Jan 13 00:00:00 1970 | 10
+ Fri Jan 23 00:00:00 1970 | 10
+ Mon Feb 02 00:00:00 1970 | 10
+ Thu Feb 12 00:00:00 1970 | 10
+ Sun Feb 22 00:00:00 1970 | 10
+ Wed Mar 04 00:00:00 1970 | 10
+ Sat Mar 14 00:00:00 1970 | 10
+ Tue Mar 24 00:00:00 1970 | 10
+ Fri Apr 03 00:00:00 1970 | 10
+(10 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, (NULL::bigint), (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY c5, (sqrt(c2)) HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Sort Key: (array_agg(ft1.c1 ORDER BY ft1.c1))
+ -> Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY c2
+(7 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5)))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Sort Key: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST))
+ -> Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY ((r2.c1 % 3))
+(7 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((ft1.c1 < 100) AND (ft1.c2 > 5))))
+ -> Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY c2
+(7 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY "C 1", c2
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY c2
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+-------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY c2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(6 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t2
+ Remote SQL: SELECT NULL FROM "S 1"."T 1"
+ -> Materialize
+ Output: t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(11 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
+(20 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Sort Key: (avg(t1.c1)), (sum(t2.c1))
+ -> Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY r2.c1 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL)))
+(7 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Seq Scan on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Filter: (t1.c2 < 10)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY "C 1"
+(15 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+ 3 | 6
+ 4 | 8
+ 5 | 10
+ 6 | 12
+ 7 | 14
+ 8 | 16
+ 9 | 18
+(9 rows)
+
+reset enable_hashagg;
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: q.b, (count(ft4.c1)), (sum(q.a))
+ Sort Key: q.b, (count(ft4.c1))
+ -> GroupAggregate
+ Output: q.b, count(ft4.c1), sum(q.a)
+ Group Key: q.b
+ -> Sort
+ Output: q.b, ft4.c1, q.a
+ Sort Key: q.b
+ -> Hash Left Join
+ Output: q.b, ft4.c1, q.a
+ Hash Cond: ((ft4.c1)::numeric = q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Hash
+ Output: q.b, q.a
+ -> Subquery Scan on q
+ Output: q.b, q.a
+ -> Foreign Scan
+ Output: (min(13)), (avg(ft1.c1)), (NULL::bigint)
+ Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
+ Remote SQL: SELECT min(13), avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
+(23 rows)
+
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+ b | count | sum
+---------------------+-------+-----
+ 12.0000000000000000 | 1 | 13
+ | 2 |
+(2 rows)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, sum(c1)
+ Group Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(7 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> GroupAggregate
+ Output: c2, c6, sum(c1)
+ Group Key: ft1.c2
+ Sort Key: ft1.c6
+ Group Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3)) ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY c2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY c2
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
-- parameterized queries
-- ===================================================================
-- simple join
@@ -2608,6 +3736,9 @@ CONTEXT: column "c8" of foreign table "ft1"
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
ERROR: invalid input syntax for integer: "foo"
CONTEXT: whole-row reference to foreign table "ft1"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for integer: "foo"
+CONTEXT: processing expression at position 2 in select list
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
-- subtransaction
@@ -4441,12 +5572,12 @@ SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
-- Consistent check constraints provide consistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
- QUERY PLAN
--------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -4485,12 +5616,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
-- But inconsistent check constraints provide inconsistent results
ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
- QUERY PLAN
---------------------------------------------------------------------
- Aggregate
- Output: count(*)
- -> Foreign Scan on public.ft1
- Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
(4 rows)
SELECT count(*) FROM ft1 WHERE c2 >= 0;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index daf0438..e267c0b 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -25,6 +25,7 @@
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/cost.h"
+#include "optimizer/clauses.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
@@ -38,6 +39,7 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/sampling.h"
+#include "utils/selfuncs.h"
PG_MODULE_MAGIC;
@@ -343,6 +345,10 @@ static void postgresGetForeignJoinPaths(PlannerInfo *root,
JoinPathExtraData *extra);
static bool postgresRecheckForeignScan(ForeignScanState *node,
TupleTableSlot *slot);
+static void postgresGetForeignUpperPaths(PlannerInfo *root,
+ UpperRelationKind stage,
+ RelOptInfo *input_rel,
+ RelOptInfo *output_rel);
/*
* Helper functions
@@ -400,11 +406,15 @@ static void conversion_error_callback(void *arg);
static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel,
JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinPathExtraData *extra);
+static bool foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel);
static List *get_useful_pathkeys_for_relation(PlannerInfo *root,
RelOptInfo *rel);
static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel);
static void add_paths_with_pathkeys_for_rel(PlannerInfo *root, RelOptInfo *rel,
Path *epq_path);
+static void add_foreign_grouping_paths(PlannerInfo *root,
+ RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel);
/*
@@ -455,6 +465,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
/* Support functions for join push-down */
routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+ /* Support functions for upper relation push-down */
+ routine->GetForeignUpperPaths = postgresGetForeignUpperPaths;
+
PG_RETURN_POINTER(routine);
}
@@ -1120,7 +1133,7 @@ postgresGetForeignPlan(PlannerInfo *root,
* rel->baserestrictinfo + parameterization clauses through
* scan_clauses. For a join rel->baserestrictinfo is NIL and we are
* not considering parameterization right now, so there should be no
- * scan_clauses for a joinrel.
+ * scan_clauses for a joinrel and upper rel either.
*/
Assert(!scan_clauses);
}
@@ -1170,7 +1183,8 @@ postgresGetForeignPlan(PlannerInfo *root,
local_exprs = lappend(local_exprs, rinfo->clause);
}
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
{
/* For a join relation, get the conditions from fdw_private structure */
remote_conds = fpinfo->remote_conds;
@@ -1191,6 +1205,13 @@ postgresGetForeignPlan(PlannerInfo *root,
{
ListCell *lc;
+ /*
+ * Right now, we only consider grouping and aggregation beyond
+ * joins. Queries involving aggregates or grouping do not require
+ * EPQ mechanism, hence should not have an outer plan here.
+ */
+ Assert(foreignrel->reloptkind != RELOPT_UPPER_REL);
+
outer_plan->targetlist = fdw_scan_tlist;
foreach(lc, local_exprs)
@@ -1228,7 +1249,8 @@ postgresGetForeignPlan(PlannerInfo *root,
remote_conds,
retrieved_attrs,
makeInteger(fpinfo->fetch_size));
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_private = lappend(fdw_private,
makeString(fpinfo->relation_name->data));
@@ -2452,7 +2474,8 @@ postgresExplainDirectModify(ForeignScanState *node, ExplainState *es)
/*
* estimate_path_cost_size
* Get cost and size estimates for a foreign scan on given foreign relation
- * either a base relation or a join between foreign relations.
+ * either a base relation or a join between foreign relations or an upper
+ * relation containing foreign relations.
*
* param_join_conds are the parameterization clauses with outer relations.
* pathkeys specify the expected sort order if any for given path being costed.
@@ -2505,7 +2528,8 @@ estimate_path_cost_size(PlannerInfo *root,
&remote_param_join_conds, &local_param_join_conds);
/* Build the list of columns to be fetched from the foreign server. */
- if (foreignrel->reloptkind == RELOPT_JOINREL)
+ if (foreignrel->reloptkind == RELOPT_JOINREL ||
+ foreignrel->reloptkind == RELOPT_UPPER_REL)
fdw_scan_tlist = build_tlist_to_deparse(foreignrel);
else
fdw_scan_tlist = NIL;
@@ -2586,25 +2610,7 @@ estimate_path_cost_size(PlannerInfo *root,
startup_cost = fpinfo->rel_startup_cost;
run_cost = fpinfo->rel_total_cost - fpinfo->rel_startup_cost;
}
- else if (foreignrel->reloptkind != RELOPT_JOINREL)
- {
- /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
- retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
-
- /*
- * Cost as though this were a seqscan, which is pessimistic. We
- * effectively imagine the local_conds are being evaluated
- * remotely, too.
- */
- startup_cost = 0;
- run_cost = 0;
- run_cost += seq_page_cost * foreignrel->pages;
-
- startup_cost += foreignrel->baserestrictcost.startup;
- cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
- run_cost += cpu_per_tuple * foreignrel->tuples;
- }
- else
+ else if (foreignrel->reloptkind == RELOPT_JOINREL)
{
PgFdwRelationInfo *fpinfo_i;
PgFdwRelationInfo *fpinfo_o;
@@ -2670,6 +2676,97 @@ estimate_path_cost_size(PlannerInfo *root,
run_cost += nrows * remote_conds_cost.per_tuple;
run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows;
}
+ else if (foreignrel->reloptkind == RELOPT_UPPER_REL)
+ {
+ PgFdwRelationInfo *ofpinfo;
+ PathTarget *ptarget = root->upper_targets[UPPERREL_GROUP_AGG];
+ AggClauseCosts aggcosts;
+ double input_rows;
+ int numGroupCols;
+ double numGroups = 1;
+
+ /*
+ * This cost model is mixture of costing done for sorted and hashed
+ * aggregates in cost_agg(). We are not sure which strategy will
+ * be considered at remote side, thus for simplicity, we put all
+ * startup related costs in startup_cost and all finalization and
+ * run cost are added in total_cost.
+ *
+ * Also, core does not care about costing HAVING expressions and
+ * adding that to the costs. So similarly, here too we are not
+ * considering remote and local conditions for costing.
+ */
+
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /* Get rows and width from input rel */
+ input_rows = ofpinfo->rows;
+ width = ofpinfo->width;
+
+ /* Collect statistics about aggregates for estimating costs. */
+ MemSet(&aggcosts, 0, sizeof(AggClauseCosts));
+ if (root->parse->hasAggs)
+ {
+ get_agg_clause_costs(root, (Node *) fpinfo->grouped_tlist,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ get_agg_clause_costs(root, (Node *) root->parse->havingQual,
+ AGGSPLIT_SIMPLE, &aggcosts);
+ }
+
+ /* Get number of grouping columns and possible number of groups */
+ numGroupCols = list_length(root->parse->groupClause);
+ numGroups = estimate_num_groups(root,
+ get_sortgrouplist_exprs(root->parse->groupClause,
+ fpinfo->grouped_tlist),
+ input_rows, NULL);
+
+ /*
+ * Number of rows expected from foreign server will be same as that
+ * of number of groups.
+ */
+ rows = retrieved_rows = numGroups;
+
+ /*
+ * Startup cost includes:
+ * 1. Startup cost for underneath input relation
+ * 2. Cost of performing aggregation, per cost_agg()
+ * 3. Startup cost for PathTarget eval
+ */
+ startup_cost = ofpinfo->rel_startup_cost;
+ startup_cost += aggcosts.transCost.startup;
+ startup_cost += aggcosts.transCost.per_tuple * input_rows;
+ startup_cost += (cpu_operator_cost * numGroupCols) * input_rows;
+ startup_cost += ptarget->cost.startup;
+
+ /*
+ * Run time cost includes:
+ * 1. Run time cost of underneath input relation
+ * 2. Run time cost of performing aggregation, per cost_agg()
+ * 4. PathTarget eval cost for each output row
+ */
+ run_cost = ofpinfo->rel_total_cost - ofpinfo->rel_startup_cost;
+ run_cost += aggcosts.finalCost * numGroups;
+ run_cost += cpu_tuple_cost * numGroups;
+ run_cost += ptarget->cost.per_tuple * numGroups;
+ }
+ else
+ {
+ /* Clamp retrieved rows estimates to at most foreignrel->tuples. */
+ retrieved_rows = Min(retrieved_rows, foreignrel->tuples);
+
+ /*
+ * Cost as though this were a seqscan, which is pessimistic. We
+ * effectively imagine the local_conds are being evaluated
+ * remotely, too.
+ */
+ startup_cost = 0;
+ run_cost = 0;
+ run_cost += seq_page_cost * foreignrel->pages;
+
+ startup_cost += foreignrel->baserestrictcost.startup;
+ cpu_per_tuple = cpu_tuple_cost + foreignrel->baserestrictcost.per_tuple;
+ run_cost += cpu_per_tuple * foreignrel->tuples;
+ }
/*
* Without remote estimates, we have no real way to estimate the cost
@@ -4343,6 +4440,326 @@ postgresGetForeignJoinPaths(PlannerInfo *root,
}
/*
+ * Assess whether the aggregation, grouping and having operations can be pushed
+ * down to the foreign server. As a side effect, save information we obtain in
+ * this function to PgFdwRelationInfo of the input relation.
+ */
+static bool
+foreign_grouping_ok(PlannerInfo *root, RelOptInfo *grouped_rel)
+{
+ Query *query = root->parse;
+ PathTarget *grouping_target;
+ PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) grouped_rel->fdw_private;
+ PgFdwRelationInfo *ofpinfo;
+ List *aggvars;
+ ListCell *lc;
+ int i;
+ List *tlist = NIL;
+
+ /* Grouping Sets are not pushable */
+ if (query->groupingSets)
+ return false;
+
+ /* Get the fpinfo of the underlying scan relation. */
+ ofpinfo = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private;
+
+ /*
+ * If underneath input relation has any local conditions, those conditions
+ * are required to be applied before performing aggregation. Hence the
+ * aggregate cannot be pushed down.
+ */
+ if (ofpinfo->local_conds)
+ return false;
+
+ /*
+ * The targetlist expected from this node and the targetlist pushed down to
+ * the foreign server may be different. The later requires sortgrouprefs to
+ * be set to push down GROUP BY clause, but should not have those arising
+ * from ORDER BY clause. These sortgrouprefs may be different from those in
+ * the plan's targetlist. Use a copy of path target to record the new
+ * sortgrouprefs.
+ */
+ grouping_target = copy_pathtarget(root->upper_targets[UPPERREL_GROUP_AGG]);
+
+ /*
+ * Evaluate grouping targets and check whether they are safe to push down
+ * to the foreign side. All GROUP BY expressions will be part of the
+ * grouping target and thus there is no need to evaluate it separately.
+ * While doing so, add required expressions into target list which
+ * can then be used to pass to foreign server.
+ */
+ i = 0;
+ foreach(lc, grouping_target->exprs)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+ Index sgref = get_pathtarget_sortgroupref(grouping_target, i);
+ ListCell *l;
+
+ /* Check whether this expression is part of GROUP BY clause */
+ if (sgref && get_sortgroupref_clause_noerr(sgref, query->groupClause))
+ {
+ /*
+ * If any of the GROUP BY expression is not shippable we can not
+ * push down aggregation to the foreign server.
+ */
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /* Check entire expression whether it is pushable or not */
+ if (is_foreign_expr(root, grouped_rel, expr))
+ {
+ /* Pushable, add to tlist */
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ else
+ {
+ /*
+ * If we have sortgroupref set, then it means that we have an
+ * ORDER BY entry pointing to this expression. Since we are
+ * not pushing ORDER BY with GROUP BY, clear it.
+ */
+ if (sgref)
+ grouping_target->sortgrouprefs[i] = 0;
+
+ /* Not matched exactly, pull the var with aggregates then */
+ aggvars = pull_var_clause((Node *) expr,
+ PVC_INCLUDE_AGGREGATES);
+
+ if (!is_foreign_expr(root, grouped_rel, (Expr *) aggvars))
+ return false;
+
+ /*
+ * Add aggregates, if any, into the targetlist. Plain var
+ * nodes should be either same as some GROUP BY expression or
+ * part of some GROUP BY expression. In later case, the query
+ * cannot refer plain var nodes without the surrounding
+ * expression. In both the cases, they are already part of
+ * the targetlist and thus no need to add them again. In fact
+ * adding pulled plain var nodes in SELECT clause will cause
+ * an error on the foreign server if they are not same as some
+ * GROUP BY expression.
+ */
+ foreach(l, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(l);
+
+ if (IsA(expr, Aggref))
+ tlist = add_to_flat_tlist(tlist, list_make1(expr));
+ }
+ }
+ }
+
+ i++;
+ }
+
+ /*
+ * Classify the pushable and non-pushable having clauses and save them in
+ * remote_conds and local_conds of grouped_rel::fpinfo.
+ */
+ if (root->hasHavingQual && query->havingQual)
+ {
+ ListCell *lc;
+
+ foreach(lc, (List *) query->havingQual)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ fpinfo->local_conds = lappend(fpinfo->local_conds, expr);
+ else
+ fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr);
+ }
+ }
+
+ /*
+ * If there are any local conditions, pull Vars and aggregates from it and
+ * check whether they are safe to pushdown or not.
+ */
+ if (fpinfo->local_conds)
+ {
+ ListCell *lc;
+ List *aggvars = pull_var_clause((Node *) fpinfo->local_conds,
+ PVC_INCLUDE_AGGREGATES);
+
+ foreach(lc, aggvars)
+ {
+ Expr *expr = (Expr *) lfirst(lc);
+
+ /*
+ * If aggregates within local conditions are not safe to push down,
+ * then we cannot push down the query. Vars are already part of
+ * GROUP BY clause which are checked above, so no need to access
+ * them again here.
+ */
+ if (IsA(expr, Aggref))
+ {
+ if (!is_foreign_expr(root, grouped_rel, expr))
+ return false;
+
+ tlist = add_to_flat_tlist(tlist, aggvars);
+ }
+ }
+ }
+
+ /* Transfer any sortgroupref data to the replacement tlist */
+ apply_pathtarget_labeling_to_tlist(tlist, grouping_target);
+ /* Store generated targetlist */
+ fpinfo->grouped_tlist = tlist;
+
+ /* Safe to pushdown */
+ fpinfo->pushdown_safe = true;
+
+ /*
+ * If user is willing to estimate cost for a scan using EXPLAIN, he intends
+ * to estimate scans on that relation more accurately. Then, it makes sense
+ * to estimate the cost of the grouping on that relation more accurately
+ * using EXPLAIN.
+ */
+ fpinfo->use_remote_estimate = ofpinfo->use_remote_estimate;
+
+ /* Copy startup and tuple cost as is from underneath input rel's fpinfo */
+ fpinfo->fdw_startup_cost = ofpinfo->fdw_startup_cost;
+ fpinfo->fdw_tuple_cost = ofpinfo->fdw_tuple_cost;
+
+ /*
+ * Set cached relation costs to some negative value, so that we can detect
+ * when they are set to some sensible costs, during one (usually the
+ * first) of the calls to estimate_path_cost_size().
+ */
+ fpinfo->rel_startup_cost = -1;
+ fpinfo->rel_total_cost = -1;
+
+ /* Set fetch size same as that of underneath input rel's fpinfo */
+ fpinfo->fetch_size = ofpinfo->fetch_size;
+
+ /*
+ * Set the string describing this grouped relation to be used in EXPLAIN
+ * output of corresponding ForeignScan.
+ */
+ fpinfo->relation_name = makeStringInfo();
+ appendStringInfo(fpinfo->relation_name, "Aggregate on (%s)",
+ ofpinfo->relation_name->data);
+
+ return true;
+}
+
+/*
+ * postgresGetForeignUpperPaths
+ * Add paths for post-join operations like aggregation, grouping etc. if
+ * corresponding operations are safe to push down.
+ *
+ * Right now, we only support aggregate, grouping and having clause pushdown.
+ */
+static void
+postgresGetForeignUpperPaths(PlannerInfo *root, UpperRelationKind stage,
+ RelOptInfo *input_rel, RelOptInfo *output_rel)
+{
+ PgFdwRelationInfo *fpinfo;
+
+ /*
+ * If input rel is not safe to pushdown, then simply return as we cannot
+ * perform any post-join operations on the foreign server.
+ */
+ if (!input_rel->fdw_private ||
+ !((PgFdwRelationInfo *) input_rel->fdw_private)->pushdown_safe)
+ return;
+
+ /*
+ * This should not happen normally. In case we have already added paths for
+ * this output rel, nothing to be done again.
+ */
+ if (output_rel->fdw_private)
+ return;
+
+ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+ fpinfo->pushdown_safe = false;
+ output_rel->fdw_private = fpinfo;
+
+ if (stage == UPPERREL_GROUP_AGG)
+ return add_foreign_grouping_paths(root, input_rel, output_rel);
+
+ /* If it's anything else, we are not adding any foreign path. */
+ return;
+}
+
+/*
+ * add_foreign_grouping_paths
+ * Add foreign path for grouping and/or aggregation.
+ *
+ * Given input_rel represents the underlying scan. The paths are added to the
+ * given grouped_rel.
+ */
+static void
+add_foreign_grouping_paths(PlannerInfo *root, RelOptInfo *input_rel,
+ RelOptInfo *grouped_rel)
+{
+ Query *parse = root->parse;
+ PgFdwRelationInfo *ifpinfo = input_rel->fdw_private;
+ PgFdwRelationInfo *fpinfo = grouped_rel->fdw_private;
+ ForeignPath *grouppath;
+ PathTarget *grouping_target;
+ double rows;
+ int width;
+ Cost startup_cost;
+ Cost total_cost;
+
+ /* Nothing to be done, if there is no grouping or aggregation required. */
+ if (!parse->groupClause && !parse->groupingSets && !parse->hasAggs &&
+ !root->hasHavingQual)
+ return;
+
+ grouping_target = root->upper_targets[UPPERREL_GROUP_AGG];
+
+ /* save the input_rel as outerrel in fpinfo */
+ fpinfo->outerrel = input_rel;
+
+ /*
+ * Copy foreign table, foreign server, user mapping, shippable extensions
+ * etc. details from underneath input relation's fpinfo.
+ */
+ fpinfo->table = ifpinfo->table;
+ fpinfo->server = ifpinfo->server;
+ fpinfo->user = ifpinfo->user;
+ fpinfo->shippable_extensions = ifpinfo->shippable_extensions;
+
+ /* Assess if it is safe to push down aggregation and grouping. */
+ if (!foreign_grouping_ok(root, grouped_rel))
+ return;
+
+ /* Estimate the cost of push down */
+ estimate_path_cost_size(root, grouped_rel, NIL, NIL, &rows,
+ &width, &startup_cost, &total_cost);
+
+ /* Now update this information in the fpinfo */
+ fpinfo->rows = rows;
+ fpinfo->width = width;
+ fpinfo->startup_cost = startup_cost;
+ fpinfo->total_cost = total_cost;
+
+ /* Create and add foreign path to the grouping relation. */
+ grouppath = create_foreignscan_path(root,
+ grouped_rel,
+ grouping_target,
+ rows,
+ startup_cost,
+ total_cost,
+ NIL, /* no pathkeys */
+ NULL, /* no required_outer */
+ NULL,
+ NULL); /* no fdw_private */
+
+ /* Add generated path into grouped_rel by add_path(). */
+ add_path(grouped_rel, (Path *) grouppath);
+
+ return;
+}
+
+/*
* Create a tuple from the specified row of the PGresult.
*
* rel is the local representation of the foreign table, attinmeta is
@@ -4549,24 +4966,34 @@ conversion_error_callback(void *arg)
ForeignScan *fsplan = (ForeignScan *) fsstate->ss.ps.plan;
EState *estate = fsstate->ss.ps.state;
TargetEntry *tle;
- Var *var;
- RangeTblEntry *rte;
Assert(IsA(fsplan, ForeignScan));
tle = (TargetEntry *) list_nth(fsplan->fdw_scan_tlist,
errpos->cur_attno - 1);
Assert(IsA(tle, TargetEntry));
- var = (Var *) tle->expr;
- Assert(IsA(var, Var));
- rte = rt_fetch(var->varno, estate->es_range_table);
+ /*
+ * Target list can have Vars and expressions. For Vars, we can get
+ * it's relation, however for expressions we can't. Thus for
+ * expressions, just show generic context message.
+ */
+ if (IsA(tle->expr, Var))
+ {
+ RangeTblEntry *rte;
+ Var *var = (Var *) tle->expr;
- if (var->varattno == 0)
- is_wholerow = true;
- else
- attname = get_relid_attribute_name(rte->relid, var->varattno);
+ rte = rt_fetch(var->varno, estate->es_range_table);
+
+ if (var->varattno == 0)
+ is_wholerow = true;
+ else
+ attname = get_relid_attribute_name(rte->relid, var->varattno);
- relname = get_rel_name(rte->relid);
+ relname = get_rel_name(rte->relid);
+ }
+ else
+ errcontext("processing expression at position %d in select list",
+ errpos->cur_attno);
}
if (relname)
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 67126bc..f8c255e 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -92,6 +92,9 @@ typedef struct PgFdwRelationInfo
RelOptInfo *innerrel;
JoinType jointype;
List *joinclauses;
+
+ /* Grouping information */
+ List *grouped_tlist;
} PgFdwRelationInfo;
/* in postgres_fdw.c */
@@ -155,7 +158,7 @@ extern void deparseAnalyzeSql(StringInfo buf, Relation rel,
List **retrieved_attrs);
extern void deparseStringLiteral(StringInfo buf, const char *val);
extern Expr *find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel);
-extern List *build_tlist_to_deparse(RelOptInfo *foreign_rel);
+extern List *build_tlist_to_deparse(RelOptInfo *foreignrel);
extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root,
RelOptInfo *foreignrel, List *tlist,
List *remote_conds, List *pathkeys,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f68e89..aeed8f6 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -541,6 +541,310 @@ ALTER VIEW v4 OWNER TO regress_view_owner;
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
+
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+
+-- Using expressions in HAVING clause
+explain (verbose, costs off)
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+select c5, count(c2) from ft1 group by c5, sqrt(c2) having sqrt(max(c2)) = sqrt(2) order by 1, 2;
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 order by 1;
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+
+-- Cleanup
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+
+
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+
+create operator family my_op_family using btree;
+
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- Now this will be pushed as sort operator is part of the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft1 t1, ft1 t2 where t1.c1 = postgres_fdw_abs(t1.c2);
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 10 order by 1;
+reset enable_hashagg;
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+
+
-- ===================================================================
-- parameterized queries
-- ===================================================================
@@ -624,6 +928,7 @@ ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
SELECT * FROM ft1 WHERE c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1.c8 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
SELECT ft1.c1, ft2.c2, ft1 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
-- ===================================================================
diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c
index 47158f6..c5be90c 100644
--- a/src/backend/optimizer/plan/createplan.c
+++ b/src/backend/optimizer/plan/createplan.c
@@ -3243,8 +3243,15 @@ create_foreignscan_plan(PlannerInfo *root, ForeignPath *best_path,
/* Copy foreign server OID; likewise, no need to make FDW do this */
scan_plan->fs_server = rel->serverid;
- /* Likewise, copy the relids that are represented by this foreign scan */
- scan_plan->fs_relids = best_path->path.parent->relids;
+ /*
+ * Likewise, copy the relids that are represented by this foreign scan. An
+ * upper rel doesn't have relids set, but it covers all the base relations
+ * participating in the underlying scan, thus use root's all_baserels.
+ */
+ if (rel->reloptkind == RELOPT_UPPER_REL)
+ scan_plan->fs_relids = root->all_baserels;
+ else
+ scan_plan->fs_relids = best_path->path.parent->relids;
/*
* If this is a foreign join, and to make it valid to push down we had to
On Thu, Oct 20, 2016 at 12:49 PM, Ashutosh Bapat <
ashutosh.bapat@enterprisedb.com> wrote:
The patch compiles and make check-world doesn't show any failures.
I have tried it. Attached separate patch for it.
However I have noticed that istoplevel is always false (at-least for the
testcase we have, I get it false always). And I also think that taking
this decision only on PlanState is enough. Does that in attached patch.
To fix this, I have passed deparse_namespace to the private argument and
accessed it in get_special_variable(). Changes looks very simple. Please
have a look and let me know your views.
This issue is not introduced by the changes done for the aggregate push
down, it only got exposed as we now ship expressions in the target list.
Thus I think it will be good if we make these changes separately as new
patch, if required.The patch looks good and pretty simple.
+ * expression. However if underneath PlanState is ForeignScanState, then + * don't force parentheses. We need to explain why it's safe not to add paranthesis. The reason this function adds paranthesis so as to preserve any operator precedences imposed by the expression tree of which this IndexVar is part. For ForeignScanState, the Var may represent the root of the expression tree, and thus not need paranthesis. But we need to verify this and explain it in the comments.As you have explained this is an issue exposed by this patch;
something not must have in this patch. If committers feel that
aggregate pushdown needs this fix as well, please provide a patch
addressing the above comment.
Sure.
Ok. PFA patch with cosmetic changes (mostly rewording comments). Let
me know if those look good. I am marking this patch is ready for
committer.
Changes look good to me.
Thanks for the detailed review.
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
On Thu, Oct 20, 2016 at 5:38 AM, Jeevan Chalke
<jeevan.chalke@enterprisedb.com> wrote:
Changes look good to me.
Thanks for the detailed review.
I didn't find anything structurally wrong with this patch, so I've
committed it with many cosmetic changes. Judging by what happened
with join pushdown, there are probably some residual bugs, but
hopefully not too many. Anyhow, I don't think waiting longer to
commit this is necessarily going to help, so let's see what happens...
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Robert Haas <robertmhaas@gmail.com> writes:
I didn't find anything structurally wrong with this patch, so I've
committed it with many cosmetic changes. Judging by what happened
with join pushdown, there are probably some residual bugs, but
hopefully not too many.
dromedary seems to have found one, or at least an unstable test result.
regards, tom lane
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Oct 21, 2016 at 10:47 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Robert Haas <robertmhaas@gmail.com> writes:
I didn't find anything structurally wrong with this patch, so I've
committed it with many cosmetic changes. Judging by what happened
with join pushdown, there are probably some residual bugs, but
hopefully not too many.dromedary seems to have found one, or at least an unstable test result.
OK, looking at that now. Thanks.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Oct 21, 2016 at 10:47 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
dromedary seems to have found one, or at least an unstable test result.
OK, looking at that now. Thanks.
Looking at further failures, it looks like 32-bit machines in general
get that result. Might be just a cost estimation difference.
Also, some of the windows machines are folding "sqrt(2)" to a different
constant than is hard-wired into the expected-result file. That's
slightly annoying because it calls into question whether we can ship
floating-point computations to the far end at all :-(.
regards, tom lane
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Oct 21, 2016 at 11:20 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Oct 21, 2016 at 10:47 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
dromedary seems to have found one, or at least an unstable test result.
OK, looking at that now. Thanks.
Looking at further failures, it looks like 32-bit machines in general
get that result. Might be just a cost estimation difference.Also, some of the windows machines are folding "sqrt(2)" to a different
constant than is hard-wired into the expected-result file. That's
slightly annoying because it calls into question whether we can ship
floating-point computations to the far end at all :-(.
IMHO, not shipping floating-point computations for that reason would
be more annoying than helpful. To really guarantee that the remote
and identical results are identical, you'd need far more
infrastructure than we have - you'd have to make sure the operating
system collations matched, for example. And we're already assuming
(without any proof) that the default collations match and, for that
matter, that the datatypes match. If you're pushing down to
PostgreSQL on the other end, you at least have a hope that the other
side might be sufficiently identical to the local side that the
results will be the same, but if somebody implements these pushdowns
for Oracle or SQL server, you almost might as well give up and go
home. Even for PostgreSQL, getting the same results in every possible
corner case requires a certain degree of optimism.
For my money, the way to handle that is to add more control over
pushdown rather than automatically disabling it in certain cases. For
example, we could have GUCs that disable all pushdown or certain types
of pushdown - e.g. you could specify that you don't trust the remote
side to sort data properly, or that you don't like it's floating-point
implementation. I'm not sure what controls are most useful here, but
I'd be willing to bet you a nice glass of white wine that many people
will be happier with a system that they can control than they will be
with one that just disables the optimization in every case where it
might hypothetically not work out. It's not clear that we can even
reasonably foresee all such cases.
--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Oct 21, 2016 at 8:50 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Oct 21, 2016 at 10:47 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
dromedary seems to have found one, or at least an unstable test result.
OK, looking at that now. Thanks.
Looking at further failures, it looks like 32-bit machines in general
get that result. Might be just a cost estimation difference.
How do I or Jeevan get to look at those results?
Also, some of the windows machines are folding "sqrt(2)" to a different
constant than is hard-wired into the expected-result file. That's
slightly annoying because it calls into question whether we can ship
floating-point computations to the far end at all :-(.
There are two things where the floating point push-down can go wrong:
a. the floating point calculation on the foreign server itself is
different from the local server, b. while converting the binary
floating point representation into text, the actual number gets
truncated because of limit on the number of digits in the text
representation. The later can be avoided by using binary data transfer
mode for floating point number. Is that something worth considering?
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Fri, Oct 21, 2016 at 9:09 PM, Robert Haas <robertmhaas@gmail.com> wrote:
On Fri, Oct 21, 2016 at 11:20 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Robert Haas <robertmhaas@gmail.com> writes:
On Fri, Oct 21, 2016 at 10:47 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
dromedary seems to have found one, or at least an unstable test result.
OK, looking at that now. Thanks.
Looking at further failures, it looks like 32-bit machines in general
get that result. Might be just a cost estimation difference.Also, some of the windows machines are folding "sqrt(2)" to a different
constant than is hard-wired into the expected-result file. That's
slightly annoying because it calls into question whether we can ship
floating-point computations to the far end at all :-(.IMHO, not shipping floating-point computations for that reason would
be more annoying than helpful.
+1
To really guarantee that the remote
and identical results are identical, you'd need far more
infrastructure than we have - you'd have to make sure the operating
system collations matched, for example. And we're already assuming
(without any proof) that the default collations match and, for that
matter, that the datatypes match. If you're pushing down to
PostgreSQL on the other end, you at least have a hope that the other
side might be sufficiently identical to the local side that the
results will be the same, but if somebody implements these pushdowns
for Oracle or SQL server, you almost might as well give up and go
home. Even for PostgreSQL, getting the same results in every possible
corner case requires a certain degree of optimism.For my money, the way to handle that is to add more control over
pushdown rather than automatically disabling it in certain cases. For
example, we could have GUCs that disable all pushdown or certain types
of pushdown - e.g. you could specify that you don't trust the remote
side to sort data properly, or that you don't like it's floating-point
implementation. I'm not sure what controls are most useful here, but
I'd be willing to bet you a nice glass of white wine that many people
will be happier with a system that they can control than they will be
with one that just disables the optimization in every case where it
might hypothetically not work out. It's not clear that we can even
reasonably foresee all such cases.
+1. But having too many of them will make the customer go crazy.
Everytime s/he stumbles upon such a problem (or bug from her/his point
of view), we will add a GUC/option OR tell, "oh! you have to turn
on/off that GUC/option". That will just make the users loose faith in
FDW (or at least postgres_fdw), if we end up with too many of them.
Instead, we may want to add the intelligence to detect when floating
point calculations on the foreign server are different from local one
OR that the default locale or collation on the foreign server are
different from the local one and accordingly set the foreign server
options automatically. This may be part of the postgres_fdw or a
separate utility. I guess, this will be similar to what configure does
to detect compatible libraries. The information gathered will
certainly become obsolete if the user re-configures the server or
changes settings, but at least we can advice them to run the utility
to detect any inconsistencies caused by changes and report or correct
them. I think this is a bigger project, separate from any FDW
pushdown.
--
Best Wishes,
Ashutosh Bapat
EnterpriseDB Corporation
The Postgres Database Company
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
brolga is still not terribly happy with this patch: it's choosing not to
push down the aggregates in one of the queries. While I failed to
duplicate that result locally, investigation suggests that brolga's result
is perfectly sane; in fact it's not very clear why we're not getting that
from multiple critters, because the plan brolga is choosing is not
inferior to the expected one.
The core of the problem is this subquery:
contrib_regression=# explain verbose select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12;
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan (cost=108.61..108.64 rows=1 width=44)
Output: (min(13)), (avg(ft1.c1)), (sum(ft2.c1))
Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
Remote SQL: SELECT min(13), avg(r1."C 1"), sum(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
(4 rows)
If you look at the estimate to just fetch the data, it's:
contrib_regression=# explain verbose select ft1.c1, ft2.c1 from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12;
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------
Foreign Scan (cost=100.55..108.62 rows=1 width=8)
Output: ft1.c1, ft2.c1
Relations: (public.ft1) INNER JOIN (public.ft2)
Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
(4 rows)
Note we're expecting only one row out of the join. Now the cost of doing
three aggregates on a single row of input is not a lot. Comparing these
local queries:
regression=# explain select min(13),avg(q1),sum(q2) from int8_tbl where q2=456;
QUERY PLAN
---------------------------------------------------------------
Aggregate (cost=1.07..1.08 rows=1 width=68)
-> Seq Scan on int8_tbl (cost=0.00..1.06 rows=1 width=16)
Filter: (q2 = 456)
(3 rows)
regression=# explain select (q1),(q2) from int8_tbl where q2=456;
QUERY PLAN
---------------------------------------------------------
Seq Scan on int8_tbl (cost=0.00..1.06 rows=1 width=16)
Filter: (q2 = 456)
(2 rows)
we seem to have startup = input cost + .01 and then another .01
for total. So the estimate to do the above remote scan and then
aggregate locally should have been 108.63 startup and 108.64 total,
give or take. The estimate for aggregating remotely is a hair better,
but it's not nearly better enough to guarantee that the planner won't
see it as fuzzily the same cost.
In short: the problem with this test case is that it's considering
aggregation over only a single row, which is a situation in which
pushing down the aggregate actually doesn't save us anything, because
we're retrieving one row from the remote either way. So it's not at all
surprising that we don't get a stable plan choice. The test query needs
to be adjusted so that the aggregation is done over multiple rows,
allowing fdw_tuple_cost to kick in and provide some daylight between
the cost estimates.
regards, tom lane
--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers
On Sat, Oct 22, 2016 at 9:09 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
brolga is still not terribly happy with this patch: it's choosing not to
push down the aggregates in one of the queries. While I failed to
duplicate that result locally, investigation suggests that brolga's result
is perfectly sane; in fact it's not very clear why we're not getting that
from multiple critters, because the plan brolga is choosing is not
inferior to the expected one.The core of the problem is this subquery:
contrib_regression=# explain verbose select min(13), avg(ft1.c1),
sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12;QUERY PLAN
------------------------------------------------------------
------------------------------------------------------------
---------------------------------
Foreign Scan (cost=108.61..108.64 rows=1 width=44)
Output: (min(13)), (avg(ft1.c1)), (sum(ft2.c1))
Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
Remote SQL: SELECT min(13), avg(r1."C 1"), sum(r2."C 1") FROM ("S 1"."T
1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" =
12))))
(4 rows)If you look at the estimate to just fetch the data, it's:
contrib_regression=# explain verbose select ft1.c1, ft2.c1 from ft1 right
join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12;
QUERY PLAN
------------------------------------------------------------
--------------------------------------------------------------------------
Foreign Scan (cost=100.55..108.62 rows=1 width=8)
Output: ft1.c1, ft2.c1
Relations: (public.ft1) INNER JOIN (public.ft2)
Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN
"S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
(4 rows)Note we're expecting only one row out of the join. Now the cost of doing
three aggregates on a single row of input is not a lot. Comparing these
local queries:regression=# explain select min(13),avg(q1),sum(q2) from int8_tbl where
q2=456;
QUERY PLAN
---------------------------------------------------------------
Aggregate (cost=1.07..1.08 rows=1 width=68)
-> Seq Scan on int8_tbl (cost=0.00..1.06 rows=1 width=16)
Filter: (q2 = 456)
(3 rows)regression=# explain select (q1),(q2) from int8_tbl where q2=456;
QUERY PLAN
---------------------------------------------------------
Seq Scan on int8_tbl (cost=0.00..1.06 rows=1 width=16)
Filter: (q2 = 456)
(2 rows)we seem to have startup = input cost + .01 and then another .01
for total. So the estimate to do the above remote scan and then
aggregate locally should have been 108.63 startup and 108.64 total,
give or take. The estimate for aggregating remotely is a hair better,
but it's not nearly better enough to guarantee that the planner won't
see it as fuzzily the same cost.In short: the problem with this test case is that it's considering
aggregation over only a single row, which is a situation in which
pushing down the aggregate actually doesn't save us anything, because
we're retrieving one row from the remote either way. So it's not at all
surprising that we don't get a stable plan choice. The test query needs
to be adjusted so that the aggregation is done over multiple rows,
allowing fdw_tuple_cost to kick in and provide some daylight between
the cost estimates.
Attached patch which performs aggrgation over 1000 rows as suggested by Tom.
I believe it will have a stable output/plan now.
Thanks
regards, tom lane
--
Jeevan B Chalke
Principal Software Engineer, Product Development
EnterpriseDB Corporation
The Enterprise PostgreSQL Company
Attachments:
agg_push_down_fix_testcase.patchbinary/octet-stream; name=agg_push_down_fix_testcase.patchDownload
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 88b696c..2745ad5 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -3123,40 +3123,32 @@ select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum fr
reset enable_hashagg;
-- Check with placeHolderVars
explain (verbose, costs off)
-select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
- QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
- Sort
- Output: q.b, (count(ft4.c1)), (sum(q.a))
- Sort Key: q.b, (count(ft4.c1))
- -> GroupAggregate
- Output: q.b, count(ft4.c1), sum(q.a)
- Group Key: q.b
- -> Sort
- Output: q.b, ft4.c1, q.a
- Sort Key: q.b
- -> Hash Left Join
- Output: q.b, ft4.c1, q.a
- Hash Cond: ((ft4.c1)::numeric = q.b)
- -> Foreign Scan on public.ft4
- Output: ft4.c1, ft4.c2, ft4.c3
- Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
- -> Hash
- Output: q.b, q.a
- -> Subquery Scan on q
- Output: q.b, q.a
- -> Foreign Scan
- Output: (min(13)), (avg(ft1.c1)), (NULL::bigint)
- Relations: Aggregate on ((public.ft1) INNER JOIN (public.ft2))
- Remote SQL: SELECT min(13), avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 12)) AND ((r1."C 1" = 12))))
-(23 rows)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: (13), (avg(ft1.c1)), (NULL::bigint)
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(16 rows)
-select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
- b | count | sum
----------------------+-------+-----
- 12.0000000000000000 | 1 | 13
- | 2 |
-(2 rows)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
-- Not supported cases
-- Grouping sets
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index bb9d41a..f48743c 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -808,8 +808,8 @@ reset enable_hashagg;
-- Check with placeHolderVars
explain (verbose, costs off)
-select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
-select q.b, count(ft4.c1), sum(q.a) from ft4 left join (select min(13), avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1) where ft1.c1 = 12) q(a, b, c) on (ft4.c1 = q.b) where ft4.c1 between 10 and 15 group by q.b order by 1 nulls last, 2;
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
-- Not supported cases