diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c index df3d1ee..42f999c 100644 --- a/contrib/postgres_fdw/deparse.c +++ b/contrib/postgres_fdw/deparse.c @@ -37,24 +37,26 @@ #include "access/heapam.h" #include "access/htup_details.h" #include "access/sysattr.h" #include "catalog/pg_collation.h" #include "catalog/pg_namespace.h" #include "catalog/pg_operator.h" #include "catalog/pg_proc.h" #include "catalog/pg_type.h" #include "commands/defrem.h" +#include "nodes/makefuncs.h" #include "nodes/nodeFuncs.h" #include "nodes/plannodes.h" #include "optimizer/clauses.h" #include "optimizer/prep.h" +#include "optimizer/tlist.h" #include "optimizer/var.h" #include "parser/parsetree.h" #include "utils/builtins.h" #include "utils/lsyscache.h" #include "utils/rel.h" #include "utils/syscache.h" /* * Global context for foreign_expr_walker's search of an expression tree. @@ -87,40 +89,55 @@ typedef struct foreign_loc_cxt /* * Context for deparseExpr */ typedef struct deparse_expr_cxt { PlannerInfo *root; /* global planner state */ RelOptInfo *foreignrel; /* the foreign relation we are planning for */ StringInfo buf; /* output buffer to append to */ List **params_list; /* exprs that will become remote Params */ + /* Outer and inner targetlists; useful for Var node lookups */ + List *outertlist; + List *innertlist; } deparse_expr_cxt; +/* All columns in foreign relation are aliased as a1, a2 etc. */ +#define COL_ALIAS_PREFIX "a" +/* + * What planner deems outer relation becomes left relation while deparsing and + * inner becomes right. The actual aliases do not matter as long as they are not + * same. + */ +#define INNER_ALIAS "r" +#define OUTER_ALIAS "l" + /* * Functions to determine whether an expression can be evaluated safely on * remote server. */ static bool foreign_expr_walker(Node *node, foreign_glob_cxt *glob_cxt, foreign_loc_cxt *outer_cxt); static char *deparse_type_name(Oid type_oid, int32 typemod); /* * Functions to construct string representation of a node tree. */ static void deparseTargetList(StringInfo buf, PlannerInfo *root, Index rtindex, Relation rel, Bitmapset *attrs_used, List **retrieved_attrs); +static void deparseExplicitTargetList(List *tlist, List **retrieved_attrs, + deparse_expr_cxt *context); static void deparseReturningList(StringInfo buf, PlannerInfo *root, Index rtindex, Relation rel, bool trig_after_row, List *returningList, List **retrieved_attrs); static void deparseColumnRef(StringInfo buf, int varno, int varattno, PlannerInfo *root); 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); @@ -134,25 +151,34 @@ static void deparseDistinctExpr(DistinctExpr *node, deparse_expr_cxt *context); static void deparseScalarArrayOpExpr(ScalarArrayOpExpr *node, deparse_expr_cxt *context); static void deparseRelabelType(RelabelType *node, deparse_expr_cxt *context); static void deparseBoolExpr(BoolExpr *node, deparse_expr_cxt *context); static void deparseNullTest(NullTest *node, deparse_expr_cxt *context); static void deparseArrayExpr(ArrayExpr *node, deparse_expr_cxt *context); static void printRemoteParam(int paramindex, Oid paramtype, int32 paramtypmod, deparse_expr_cxt *context); static void printRemotePlaceholder(Oid paramtype, int32 paramtypmod, deparse_expr_cxt *context); -static void deparseSelectSql(Bitmapset *attrs_used, List **retrieved_attrs, - deparse_expr_cxt *context); +static void deparseSelectSqlForBaseRel(List *tlist, StringInfo relation, + List **retrieved_attrs, deparse_expr_cxt *context); static void deparseLockingClause(deparse_expr_cxt *context); -static void appendWhereClause(List *exprs, deparse_expr_cxt *context); static void appendOrderByClause(List *pathkeys, deparse_expr_cxt *context); +static const char *get_jointype_name(JoinType jointype); +static void appendConditions(List *exprs, deparse_expr_cxt *context); +static void deparseJoinExpr(const char *sql_o, const char *sql_i, + JoinType jointype, List *joinclauses, + deparse_expr_cxt *context); +static void deparseColumnRefForJoinRel(Var *node, deparse_expr_cxt *context); +static void deparseColumnRefForBaseRel(Var *var, deparse_expr_cxt *context); +static void deparseAlias(StringInfo buf, List *tlist); +static void deparseSelectSqlForJoinRel(List *tlist, StringInfo relations, + List **retrieved_attrs, deparse_expr_cxt *context); /* * Examine each qual clause in input_conds, and classify them into two groups, * which are returned as two lists: * - remote_conds contains expressions that can be evaluated remotely * - local_conds contains expressions that can't be evaluated remotely */ void classifyConditions(PlannerInfo *root, @@ -261,21 +287,21 @@ foreign_expr_walker(Node *node, { Var *var = (Var *) node; /* * If the Var is from the foreign table, we consider its * collation (if any) safe to use. If it is from another * table, we treat its collation the same way as we would a * Param's collation, ie it's not safe for it to have a * non-default collation. */ - if (var->varno == glob_cxt->foreignrel->relid && + if (bms_is_member(var->varno, glob_cxt->foreignrel->relids) && var->varlevelsup == 0) { /* Var belongs to foreign table */ /* * System columns other than ctid should not be sent to * the remote, since we don't make any effort to ensure * that local and remote values match (tableoid, in * particular, almost certainly doesn't match). */ @@ -696,126 +722,308 @@ foreign_expr_walker(Node *node, static char * deparse_type_name(Oid type_oid, int32 typemod) { if (is_builtin(type_oid)) return format_type_with_typemod(type_oid, typemod); else return format_type_with_typemod_qualified(type_oid, 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. + */ +List * +build_tlist_to_deparse(RelOptInfo *foreignrel) +{ + List *tlist = NIL; + PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private; + + /* + * We require columns specified in foreignrel->reltargetlist and those + * required for evaluating the local conditions. + */ + tlist = add_to_flat_tlist(tlist, foreignrel->reltargetlist); + tlist = add_to_flat_tlist(tlist, + pull_var_clause((Node *)fpinfo->local_conds, + PVC_REJECT_AGGREGATES, + PVC_RECURSE_PLACEHOLDERS)); + + return tlist; +} + +/* * Deparse SELECT statement for given relation into buf. * - * remote_conds is the list of conditions to be deparsed as WHERE clause. + * Function is the entry point to deparse routines while constructing + * ForeignScan plan or estimating cost and size for ForeignPath. It is called + * recursively to build SELECT statements for joining relations of a pushed down + * foreign join. * - * pathkeys is the list of pathkeys to order the result by. + * tlist contains the list of desired columns to be fetched from foreign server. + * While constructing SELECT statement for a join push down, a caller passes + * tlist for given relation. The caller uses the same tlist to construct the + * tuple descriptor for the corresponding foreign scan. For a base relation, + * which is not part of a pushed down join, fpinfo->attrs_used can be used to + * construct SELECT clause, thus the function doesn't need tlist. Hence when + * tlist passed, the function assumes that it's constructing the SELECT + * statement to be part of a pushed down foreign join. * - * List of columns selected is returned in retrieved_attrs. + * remote_conds is the list of conditions to be deparsed as WHERE 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 * server as parameter values. * * If params_list is NULL, we're generating the query for EXPLAIN purposes, * so Params and other-relation Vars should be replaced by dummy values. + * + * pathkeys is the list of pathkeys to order the result by. + * + * List of columns selected is returned in retrieved_attrs, if the caller has + * requested it. We expect that retrieved_attrs will be required only for the + * top relation in pushed down join hierarchy (may be a base relation which is + * not part of a pushed down foreign join). For a join relation (when tlist is + * passed) it's merely a list of continuously increasing integers starting from + * 1, since those are the attribute numbers are in the corresponding scan. + * + * relations is a string buffer for "Relations" portion of EXPLAIN output, + * or NULL if caller doesn't need it. Note that it should have been + * initialized by caller. */ extern void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, RelOptInfo *rel, List *remote_conds, List *pathkeys, - List **retrieved_attrs, List **params_list) + List **retrieved_attrs, List **params_list, + List *tlist, StringInfo relations) { - PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) rel->fdw_private; deparse_expr_cxt context; - /* Initialize params_list if caller needs one */ - if (params_list) - *params_list = NIL; + /* 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); + /* Fill portions of context common to join and base relation */ context.buf = buf; context.root = root; context.foreignrel = rel; context.params_list = params_list; - deparseSelectSql(fpinfo->attrs_used, retrieved_attrs, &context); + /* Construct SELECT clause and FROM clause */ + if (rel->reloptkind == RELOPT_JOINREL) + deparseSelectSqlForJoinRel(tlist, relations, retrieved_attrs, &context); + else + deparseSelectSqlForBaseRel(tlist, relations, retrieved_attrs, &context); + /* + * Construct WHERE clause + */ if (remote_conds) - appendWhereClause(remote_conds, &context); + { + appendStringInfo(buf, " WHERE "); + appendConditions(remote_conds, &context); + } /* Add ORDER BY clause if we found any useful pathkeys */ if (pathkeys) appendOrderByClause(pathkeys, &context); - /* Add any necessary FOR UPDATE/SHARE. */ - deparseLockingClause(&context); + /* + * Add any necessary FOR UPDATE/SHARE. + * XXX + * Since the query is being built in recursive manner from bottom up, + * the FOR UPDATE/SHARE clause referring the base relations can not be added + * at the top level. They need to be added to the subqueries corresponding + * to the base relations. This has an undesirable effect of locking more + * rows than specified by user, as it locks even those rows from base + * relations which are not part of the final join result. To avoid this + * undesirable effect, we need to build the join query without the + * subqueries, which for now, seems hard. + */ + + if (rel->reloptkind != RELOPT_JOINREL) + deparseLockingClause(&context); } /* * 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 tablename". * * We also create an integer List of the columns being retrieved, which is - * returned to *retrieved_attrs. + * returned to *retrieved_attrs. Read description of retrieved_attrs in + * deparseSelectStmtForRel() for more details. + * + * tlist is the list of desired columns. For details read prologue of + * deparseSelectStmtForRel(). */ -void -deparseSelectSql(Bitmapset *attrs_used, List **retrieved_attrs, - deparse_expr_cxt *context) +static void +deparseSelectSqlForBaseRel(List *tlist, StringInfo relation, + List **retrieved_attrs, deparse_expr_cxt *context) { StringInfo buf = context->buf; RelOptInfo *foreignrel = context->foreignrel; PlannerInfo *root = context->root; RangeTblEntry *rte = planner_rt_fetch(foreignrel->relid, root); Relation rel; + PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private; /* * Core code already has some lock on each rel being planned, so we can * use NoLock here. */ rel = heap_open(rte->relid, NoLock); + /* No inner and outer targetlists for base relation. */ + context->outertlist = NIL; + context->innertlist = NIL; + /* * Construct SELECT list */ appendStringInfoString(buf, "SELECT "); - deparseTargetList(buf, root, foreignrel->relid, rel, attrs_used, - retrieved_attrs); + + /* + * If the caller has provided required targetlist, use it to construct + * the SELECT clause. Otherwise, use fpinfo->attrs_used. + */ + if (tlist) + deparseExplicitTargetList(tlist, retrieved_attrs, context); + else + deparseTargetList(buf, root, foreignrel->relid, rel, fpinfo->attrs_used, + retrieved_attrs); /* * Construct FROM clause */ appendStringInfoString(buf, " FROM "); deparseRelation(buf, rel); + /* + * Return local relation name for EXPLAIN output. + * We can't know whether VERBOSE option is specified or not, so always + * schema-qualify the foreign table name. + */ + if (relation) + { + const char *namespace; + const char *relname; + const char *refname; + + namespace = get_namespace_name(get_rel_namespace(rte->relid)); + relname = get_rel_name(rte->relid); + refname = rte->eref->aliasname; + appendStringInfo(relation, "%s.%s", + quote_identifier(namespace), + quote_identifier(relname)); + if (*refname && strcmp(refname, relname) != 0) + appendStringInfo(relation, " %s", + quote_identifier(rte->eref->aliasname)); + } heap_close(rel, NoLock); } /* + * Construct a simple SELECT statement that retrieves desired columns + * of the specified foreign join relation, and append it to "buf". The output + * contains just "SELECT ... FROM ". + * + * We also create an integer List of the columns being retrieved, which is + * returned to *retrieved_attrs. Read description of retrieved_attrs in + * deparseSelectStmtForRel() for more details. + */ +static void +deparseSelectSqlForJoinRel(List *tlist, StringInfo relations, + List **retrieved_attrs, deparse_expr_cxt *context) +{ + RelOptInfo *foreignrel = context->foreignrel; + PlannerInfo *root = context->root; + List **params_list = context->params_list; + StringInfo buf = context->buf; + PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private; + RelOptInfo *rel_o = fpinfo->outerrel; + RelOptInfo *rel_i = fpinfo->innerrel; + PgFdwRelationInfo *fpinfo_o = (PgFdwRelationInfo *) rel_o->fdw_private; + PgFdwRelationInfo *fpinfo_i = (PgFdwRelationInfo *) rel_i->fdw_private; + StringInfoData sql_o; + StringInfoData sql_i; + StringInfo relations_o = NULL; + StringInfo relations_i = NULL; + List *tlist_i = NIL; /* Inner relation targetlist */ + List *tlist_o = NIL; /* Outer relation targetlist */ + + if (relations) + { + relations_o = makeStringInfo(); + relations_i = makeStringInfo(); + } + + /* + * For a join relation, recursively construct SELECT query for + * outer and inner relations + */ + /* Deparse query for outer relation */ + initStringInfo(&sql_o); + tlist_o = build_tlist_to_deparse(rel_o); + deparseSelectStmtForRel(&sql_o, root, rel_o, fpinfo_o->remote_conds, + NIL, NULL, params_list, tlist_o, relations_o); + + /* Deparse query for inner relation */ + initStringInfo(&sql_i); + tlist_i = build_tlist_to_deparse(rel_i); + deparseSelectStmtForRel(&sql_i, root, rel_i, fpinfo_i->remote_conds, + NIL, NULL, params_list, tlist_i, relations_i); + + /* If requested, let caller know what's being joined */ + if (relations) + appendStringInfo(relations, "(%s) %s JOIN (%s)", + relations_o->data, + get_jointype_name(fpinfo->jointype), + relations_i->data); + + context->outertlist = tlist_o; + context->innertlist = tlist_i; + + /* Construct SELECT clause of the join scan */ + appendStringInfo(buf, "SELECT "); + deparseExplicitTargetList(tlist, retrieved_attrs, context); + + /* Combine inner and outer queries into JOIN clause */ + deparseJoinExpr(sql_o.data, sql_i.data, fpinfo->jointype, + fpinfo->joinclauses, context); +} + +/* * Emit a target list that retrieves the columns specified in attrs_used. * This is used for both SELECT and RETURNING targetlists. * * The tlist text is appended to buf, and we also create an integer List * of the columns being retrieved, which is returned to *retrieved_attrs. */ static void deparseTargetList(StringInfo buf, PlannerInfo *root, Index rtindex, Relation rel, Bitmapset *attrs_used, List **retrieved_attrs) { TupleDesc tupdesc = RelationGetDescr(rel); bool have_wholerow; bool first; int i; - *retrieved_attrs = NIL; + if (retrieved_attrs) + *retrieved_attrs = NIL; /* If there's a whole-row reference, we'll need all the columns. */ have_wholerow = bms_is_member(0 - FirstLowInvalidHeapAttributeNumber, attrs_used); first = true; for (i = 1; i <= tupdesc->natts; i++) { Form_pg_attribute attr = tupdesc->attrs[i - 1]; @@ -826,39 +1034,41 @@ deparseTargetList(StringInfo buf, if (have_wholerow || bms_is_member(i - FirstLowInvalidHeapAttributeNumber, attrs_used)) { if (!first) appendStringInfoString(buf, ", "); first = false; deparseColumnRef(buf, rtindex, i, root); - *retrieved_attrs = lappend_int(*retrieved_attrs, i); + if (retrieved_attrs) + *retrieved_attrs = lappend_int(*retrieved_attrs, i); } } /* * Add ctid if needed. We currently don't support retrieving any other * system columns. */ if (bms_is_member(SelfItemPointerAttributeNumber - FirstLowInvalidHeapAttributeNumber, attrs_used)) { if (!first) appendStringInfoString(buf, ", "); first = false; appendStringInfoString(buf, "ctid"); - *retrieved_attrs = lappend_int(*retrieved_attrs, - SelfItemPointerAttributeNumber); + if (retrieved_attrs) + *retrieved_attrs = lappend_int(*retrieved_attrs, + SelfItemPointerAttributeNumber); } /* Don't generate bad syntax if no undropped columns */ if (first) appendStringInfoString(buf, "NULL"); } /* * Deparse the appropriate locking clause (FOR SELECT or FOR SHARE) for a * given relation (context->foreignrel). @@ -915,55 +1125,285 @@ deparseLockingClause(deparse_expr_cxt *context) case LCS_FORNOKEYUPDATE: case LCS_FORUPDATE: appendStringInfoString(buf, " FOR UPDATE"); break; } } } } /* - * Deparse WHERE clauses in given list of RestrictInfos and append them to - * context->buf. + * 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. */ static void -appendWhereClause(List *exprs, deparse_expr_cxt *context) +appendConditions(List *exprs, deparse_expr_cxt *context) { int nestlevel; ListCell *lc; bool is_first = true; StringInfo buf = context->buf; /* Make sure any constants in the exprs are printed portably */ nestlevel = set_transmission_modes(); foreach(lc, exprs) { - RestrictInfo *ri = (RestrictInfo *) lfirst(lc); + Expr *expr = (Expr *) lfirst(lc); + + /* + * Extract clause from RestrictInfo, if required. See comments in + * declaration of PgFdwRelationInfo for details. + */ + if (IsA(expr, RestrictInfo)) + { + RestrictInfo *ri = (RestrictInfo *) expr; + expr = ri->clause; + } /* Connect expressions with "AND" and parenthesize each condition. */ - if (is_first) - appendStringInfoString(buf, " WHERE "); - else + if (!is_first) appendStringInfoString(buf, " AND "); appendStringInfoChar(buf, '('); - deparseExpr(ri->clause, context); + deparseExpr(expr, context); appendStringInfoChar(buf, ')'); is_first = false; } reset_transmission_modes(nestlevel); } /* + * Construct the name of the column specified by Var as + * "side alias"."column alias" for the joinrel provided in the context. + * + * side alias is l for left (outer) side of the join and r for right (inner) + * side of the join. + * + * column alias is aN where N is the position of given Var node in left or right + * targetlist, wherever it's found. + */ +static void +deparseColumnRefForJoinRel(Var *var, deparse_expr_cxt *context) +{ + char *side; + TargetEntry *tle; + + /* Lookup outer side */ + tle = tlist_member((Node *)var, context->outertlist); + if (tle) + side = OUTER_ALIAS; + else + { + /* Not found on outer side; lookup inner */ + side = INNER_ALIAS; + tle = tlist_member((Node *)var, context->innertlist); + } + + /* The input var should be either on left or right side */ + Assert(tle && side); + + appendStringInfo(context->buf, "%s.%s%d", side, COL_ALIAS_PREFIX, tle->resno); +} + +/* + * Emit the name of column specified by Var node into buffer in the context. + * + * This function handles whole-row reference and ctid by itself and delegates + * deparsing rest of the columns to deparseColumnRef. + */ +static void +deparseColumnRefForBaseRel(Var *var, deparse_expr_cxt *context) +{ + StringInfo buf = context->buf; + PlannerInfo *root = context->root; + + /* varattno can be a whole-row reference, ctid or a regular table column */ + if (var->varattno == SelfItemPointerAttributeNumber) + appendStringInfoString(buf, "ctid"); + else if (var->varattno == 0) + { + /* Whole row reference */ + + /* Get RangeTblEntry from array in PlannerInfo. */ + RangeTblEntry *rte = planner_rt_fetch(var->varno, root); + /* + * The lock on the relation will be held by upper callers, so it's + * fine to open it with no lock here. + */ + Relation rel = heap_open(rte->relid, NoLock); + Bitmapset *attrs_used; + + /* + * The local name of the foreign table can not be recognized by the + * foreign server and the table it references on foreign server + * might have different column ordering or different columns than + * those declared locally. Hence we have to deparse whole-row + * reference as ROW(columns referenced locally). Construct this by + * deparsing a "whole row" attribute. + */ + attrs_used = bms_add_member(NULL, + 0 - FirstLowInvalidHeapAttributeNumber); + appendStringInfoString(buf, "ROW("); + deparseTargetList(buf, root, var->varno, rel, attrs_used, NULL); + appendStringInfoString(buf, ")"); + heap_close(rel, NoLock); + bms_free(attrs_used); + } + else + deparseColumnRef(buf, var->varno, var->varattno, root); +} + +/* + * Deparse column alias list for a subquery in FROM clause. + * + * The function creates string "a1, a2, ... aN", where N is the number of + * entries in the input targetlist. + */ +static void +deparseAlias(StringInfo buf, List *tlist) +{ + int pos; + ListCell *lc; + + pos = 1; + foreach(lc, tlist) + { + /* Deparse column alias for the subquery */ + if (pos > 1) + appendStringInfoString(buf, ", "); + appendStringInfo(buf, "%s%d", COL_ALIAS_PREFIX, pos); + pos++; + } +} + +/* Output join name for given join type */ +static const char * +get_jointype_name(JoinType jointype) +{ + switch(jointype) + { + case JOIN_INNER: + return "INNER"; + + case JOIN_LEFT: + return "LEFT"; + + case JOIN_RIGHT: + return "RIGHT"; + + case JOIN_FULL: + return "FULL"; + + default: + /* Shouldn't come here, but protect from buggy code. */ + elog(ERROR, "unsupported join type %d", jointype); + } + + /* Keep compiler happy */ + return NULL; +} + +/* + * Deparse given targetlist and append it to context->buf. + * + * tlist is list of TargetEntry's which in turn contain Var nodes. + * + * retrieved_attrs, if requested, is the list of continuously increasing + * integers starting from 1. It has same number of entries as tlist. + */ +static void +deparseExplicitTargetList(List *tlist, List **retrieved_attrs, + deparse_expr_cxt *context) +{ + ListCell *lc; + StringInfo buf = context->buf; + int i = 0; + + if (retrieved_attrs) + *retrieved_attrs = NIL; + + 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 */ + Assert(IsA(var, Var)); + + if (i > 0) + appendStringInfoString(buf, ", "); + deparseVar(var, context); + + if (retrieved_attrs) + *retrieved_attrs = lappend_int(*retrieved_attrs, i + 1); + + i++; + } + + if (i == 0) + appendStringInfoString(buf, "NULL"); + +} + +/* + * Construct a FROM ... JOIN ... ON ... for join relation in context. + * + * sql_o and sql_id are SELECT statements for outer and inner side + * respectively. jointype and joinclauses indicate the type of join and join + * conditions resp. + */ +void +deparseJoinExpr(const char *sql_o, const char *sql_i, JoinType jointype, + List *joinclauses, deparse_expr_cxt *context) +{ + StringInfo buf = context->buf; + + /* Construct FROM clause */ + appendStringInfo(buf, " FROM "); + + /* + * Construct left relation with column aliases + * as (left query) l (a1, a2, ... aN) + */ + appendStringInfo(buf, "(%s) %s (", sql_o, OUTER_ALIAS); + deparseAlias(buf, context->outertlist); + appendStringInfo(buf, ")"); + + /* Add join type */ + appendStringInfo(buf, " %s JOIN ", get_jointype_name(jointype)); + + /* + * Construct right relation with column aliases + * as (right query) r (a1, a2, ... aM) + */ + appendStringInfo(buf, "(%s) %s (", sql_i, INNER_ALIAS); + deparseAlias(buf, context->innertlist); + appendStringInfo(buf, ")"); + + /* Append ON clause; ON (TRUE) in case empty join clause list */ + appendStringInfoString(buf, " ON "); + if (joinclauses) + appendConditions(joinclauses, context); + else + appendStringInfoString(buf, "(TRUE)"); + + return; +} + +/* * deparse remote INSERT statement * * The statement text is appended to buf, and we also create an integer List * of the columns being retrieved by RETURNING (if any), which is returned * to *retrieved_attrs. */ void deparseInsertSql(StringInfo buf, PlannerInfo *root, Index rtindex, Relation rel, List *targetAttrs, bool doNothing, @@ -1384,27 +1824,28 @@ deparseExpr(Expr *node, deparse_expr_cxt *context) * Deparse given Var node into context->buf. * * If the Var belongs to the foreign relation, just print its remote name. * Otherwise, it's effectively a Param (and will in fact be a Param at * run time). Handle it the same way we handle plain Params --- see * deparseParam for comments. */ static void deparseVar(Var *node, deparse_expr_cxt *context) { - StringInfo buf = context->buf; - - if (node->varno == context->foreignrel->relid && + if (bms_is_member(node->varno, context->foreignrel->relids) && node->varlevelsup == 0) { - /* Var belongs to foreign table */ - deparseColumnRef(buf, node->varno, node->varattno, context->root); + /* Var belongs to foreign table or join between foreign tables.*/ + if (context->foreignrel->reloptkind == RELOPT_JOINREL) + deparseColumnRefForJoinRel(node, context); + else + deparseColumnRefForBaseRel(node, context); } else { /* Treat like a Param */ if (context->params_list) { int pindex = 0; ListCell *lc; /* find its index in params_list */ diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index 2390e61..ab1991c 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -2,25 +2,30 @@ -- create FDW objects -- =================================================================== CREATE EXTENSION postgres_fdw; CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw; DO $d$ BEGIN EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw OPTIONS (dbname '$$||current_database()||$$', port '$$||current_setting('port')||$$' )$$; + EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw + OPTIONS (dbname '$$||current_database()||$$', + port '$$||current_setting('port')||$$' + )$$; END; $d$; CREATE USER MAPPING FOR public SERVER testserver1 OPTIONS (user 'value', password 'value'); CREATE USER MAPPING FOR CURRENT_USER SERVER loopback; +CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2; -- =================================================================== -- create objects used through FDW loopback server -- =================================================================== CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz'); CREATE SCHEMA "S 1"; CREATE TABLE "S 1"."T 1" ( "C 1" int NOT NULL, c2 int NOT NULL, c3 text, c4 timestamptz, @@ -28,36 +33,62 @@ CREATE TABLE "S 1"."T 1" ( c6 varchar(10), c7 char(10), c8 user_enum, CONSTRAINT t1_pkey PRIMARY KEY ("C 1") ); CREATE TABLE "S 1"."T 2" ( c1 int NOT NULL, c2 text, CONSTRAINT t2_pkey PRIMARY KEY (c1) ); +CREATE TABLE "S 1"."T 3" ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text, + CONSTRAINT t3_pkey PRIMARY KEY (c1) +); +CREATE TABLE "S 1"."T 4" ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text, + CONSTRAINT t4_pkey PRIMARY KEY (c1) +); INSERT INTO "S 1"."T 1" SELECT id, id % 10, to_char(id, 'FM00000'), '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval, '1970-01-01'::timestamp + ((id % 100) || ' days')::interval, id % 10, id % 10, 'foo'::user_enum FROM generate_series(1, 1000) id; INSERT INTO "S 1"."T 2" SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id; +INSERT INTO "S 1"."T 3" + SELECT id, + id + 1, + 'AAA' || to_char(id, 'FM000') + FROM generate_series(1, 100) id; +DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests +INSERT INTO "S 1"."T 4" + SELECT id, + id + 1, + 'AAA' || to_char(id, 'FM000') + FROM generate_series(1, 100) id; +DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests ANALYZE "S 1"."T 1"; ANALYZE "S 1"."T 2"; +ANALYZE "S 1"."T 3"; +ANALYZE "S 1"."T 4"; -- =================================================================== -- create foreign tables -- =================================================================== CREATE FOREIGN TABLE ft1 ( c0 int, c1 int NOT NULL, c2 int NOT NULL, c3 text, c4 timestamptz, c5 timestamp, @@ -71,20 +102,35 @@ CREATE FOREIGN TABLE ft2 ( c2 int NOT NULL, cx int, c3 text, c4 timestamptz, c5 timestamp, c6 varchar(10), c7 char(10) default 'ft2', c8 user_enum ) SERVER loopback; ALTER FOREIGN TABLE ft2 DROP COLUMN cx; +CREATE FOREIGN TABLE ft4 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3'); +CREATE FOREIGN TABLE ft5 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4'); +CREATE FOREIGN TABLE ft6 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4'); -- =================================================================== -- tests for validator -- =================================================================== -- requiressl, krbsrvname and gsslib are omitted because they depend on -- configure options ALTER SERVER testserver1 OPTIONS ( use_remote_estimate 'false', updatable 'true', fdw_startup_cost '123.456', fdw_tuple_cost '0.123', @@ -120,26 +166,29 @@ ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar'); WARNING: extension "foo" is not installed WARNING: extension "bar" is not installed ALTER SERVER testserver1 OPTIONS (DROP extensions); ALTER USER MAPPING FOR public SERVER testserver1 OPTIONS (DROP user, DROP password); ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1'); ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1'); ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1'); ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1'); \det+ - List of foreign tables - Schema | Table | Server | FDW Options | Description ---------+-------+----------+---------------------------------------+------------- - public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') | - public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') | -(2 rows) + List of foreign tables + Schema | Table | Server | FDW Options | Description +--------+-------+-----------+---------------------------------------+------------- + public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') | + public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') | + public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') | + public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') | + public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') | +(5 rows) -- Now we should be able to run ANALYZE. -- To exercise multiple code paths, we use local stats on ft1 -- and remote-estimate mode on ft2. ANALYZE ft1; ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true'); -- =================================================================== -- simple queries -- =================================================================== -- single table without alias @@ -274,36 +323,20 @@ SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE; 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo (1 row) -- aggregate SELECT COUNT(*) FROM ft1 t1; count ------- 1000 (1 row) --- join two tables -SELECT t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; - c1 ------ - 101 - 102 - 103 - 104 - 105 - 106 - 107 - 108 - 109 - 110 -(10 rows) - -- subquery SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1; c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 ----+----+-------+------------------------------+--------------------------+----+------------+----- 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo @@ -506,30 +539,30 @@ EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote QUERY PLAN ------------------------------------------------------------------------- Foreign Scan on public.ft1 t1 Output: c1, c2, c3, c4, c5, c6, c7, c8 Filter: (t1.c8 = 'foo'::user_enum) Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" (4 rows) --- parameterized remote path +-- parameterized remote path for foreign table EXPLAIN (VERBOSE, COSTS false) - SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2; + SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2; QUERY PLAN ------------------------------------------------------------------------------------------------------------- Nested Loop - Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8 - -> Foreign Scan on public.ft2 a - Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8 - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 47)) + Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8 + -> Index Scan using t1_pkey on "S 1"."T 1" a + Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8 + Index Cond: (a."C 1" = 47) -> Foreign Scan on public.ft2 b Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8 Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1")) (8 rows) SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2; c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 ----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+----- 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo (1 row) @@ -820,36 +853,959 @@ EXPLAIN (VERBOSE, COSTS false) Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) (5 rows) SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2; count ------- 9 (1 row) -- =================================================================== +-- JOIN queries +-- =================================================================== +-- Analyze ft4 and ft5 so that we have better statistics. These tables do not +-- have use_remote_estimate set. +ANALYZE ft4; +ANALYZE ft5; +-- join two tables +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3 + -> Sort + Output: t1.c1, t2.c1, t1.c3 + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3 + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, r.a1 FROM (SELECT "C 1", c3 FROM "S 1"."T 1") l (a1, a2) INNER JOIN (SELECT "C 1" FROM "S 1"."T 1") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) +(9 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- join three tables +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + Limit + Output: t1.c1, t2.c2, t3.c3, t1.c3 + -> Sort + Output: t1.c1, t2.c2, t3.c3, t1.c3 + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c2, t3.c3, t1.c3 + Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3) + Remote SQL: SELECT l.a1, l.a2, l.a3, r.a1 FROM (SELECT l.a1, l.a2, r.a1, r.a2 FROM (SELECT "C 1", c3 FROM "S 1"."T 1") l (a1, a2) INNER JOIN (SELECT c2, "C 1" FROM "S 1"."T 1") r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a2))) l (a1, a2, a3, a4) INNER JOIN (SELECT c3, c1 FROM "S 1"."T 3") r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a2)) +(9 rows) + +SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10; + c1 | c2 | c3 +----+----+-------- + 22 | 2 | AAA022 + 24 | 4 | AAA024 + 26 | 6 | AAA026 + 28 | 8 | AAA028 + 30 | 0 | AAA030 + 32 | 2 | AAA032 + 34 | 4 | AAA034 + 36 | 6 | AAA036 + 38 | 8 | AAA038 + 40 | 0 | AAA040 +(10 rows) + +-- left outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 3") l (a1) LEFT JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON ((l.a1 = r.a1)) +(9 rows) + +SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; + c1 | c1 +----+---- + 22 | + 24 | 24 + 26 | + 28 | + 30 | 30 + 32 | + 34 | + 36 | 36 + 38 | + 40 | +(10 rows) + +-- left outer join + placement of clauses. +-- clauses within the nullable side are not pulled up, but top level clause on +-- non-nullable side is pushed into non-nullable side +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10; + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Foreign Scan + Output: t1.c1, t1.c2, ft5.c1, ft5.c2 + Relations: (public.ft4 t1) LEFT JOIN (public.ft5) + Remote SQL: SELECT l.a1, l.a2, r.a1, r.a2 FROM (SELECT c1, c2 FROM "S 1"."T 3" WHERE ((c1 < 10))) l (a1, a2) LEFT JOIN (SELECT c1, c2 FROM "S 1"."T 4" WHERE ((c1 < 10))) r (a1, a2) ON ((l.a1 = r.a1)) +(4 rows) + +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10; + c1 | c2 | c1 | c2 +----+----+----+---- + 2 | 3 | | + 4 | 5 | | + 6 | 7 | 6 | 7 + 8 | 9 | | +(4 rows) + +-- clauses within the nullable side are not pulled up, but the top level clause +-- on nullable side is not pushed down into nullable side +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) + WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10; + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Foreign Scan + Output: t1.c1, t1.c2, ft5.c1, ft5.c2 + Relations: (public.ft4 t1) LEFT JOIN (public.ft5) + Remote SQL: SELECT l.a1, l.a2, r.a1, r.a2 FROM (SELECT c1, c2 FROM "S 1"."T 3" WHERE ((c1 < 10))) l (a1, a2) LEFT JOIN (SELECT c1, c2 FROM "S 1"."T 4" WHERE ((c1 < 10))) r (a1, a2) ON ((l.a1 = r.a1)) WHERE (((r.a1 < 10) OR (r.a1 IS NULL))) +(4 rows) + +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) + WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10; + c1 | c2 | c1 | c2 +----+----+----+---- + 2 | 3 | | + 4 | 5 | | + 6 | 7 | 6 | 7 + 8 | 9 | | +(4 rows) + +-- right outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t2.c1, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 3") l (a1) LEFT JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON ((r.a1 = l.a1)) +(9 rows) + +SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10; + c1 | c1 +----+---- + | 22 + 24 | 24 + | 26 + | 28 + 30 | 30 + | 32 + | 34 + 36 | 36 + | 38 + | 40 +(10 rows) + +-- full outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 3") l (a1) FULL JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON ((l.a1 = r.a1)) +(9 rows) + +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10; + c1 | c1 +-----+---- + 92 | + 94 | + 96 | 96 + 98 | + 100 | + | 3 + | 9 + | 15 + | 21 + | 27 +(10 rows) + +-- full outer join + WHERE clause, only matched rows +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 3") l (a1) FULL JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON ((l.a1 = r.a1)) WHERE (((l.a1 = r.a1) OR (l.a1 IS NULL))) +(9 rows) + +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; + c1 | c1 +----+---- + 66 | 66 + 72 | 72 + 78 | 78 + 84 | 84 + 90 | 90 + 96 | 96 + | 3 + | 9 + | 15 + | 21 +(10 rows) + +-- join two tables with FOR UPDATE clause +-- tests whole-row reference for row marks +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1; + QUERY PLAN +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> LockRows + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> Sort + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, l.a3, r.a1, r.a2 FROM (SELECT "C 1", c3, ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR UPDATE) l (a1, a2, a3) INNER JOIN (SELECT "C 1", ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1") r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Merge Join + Output: t1.c1, t1.c3, t1.*, t2.c1, t2.* + Merge Cond: (t1.c1 = t2.c1) + -> Sort + Output: t1.c1, t1.c3, t1.* + Sort Key: t1.c1 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c3, t1.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR UPDATE + -> Sort + Output: t2.c1, t2.* + Sort Key: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1, t2.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" +(26 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> LockRows + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> Sort + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, l.a3, r.a1, r.a2 FROM (SELECT "C 1", c3, ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR UPDATE) l (a1, a2, a3) INNER JOIN (SELECT "C 1", ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR UPDATE) r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Merge Join + Output: t1.c1, t1.c3, t1.*, t2.c1, t2.* + Merge Cond: (t1.c1 = t2.c1) + -> Sort + Output: t1.c1, t1.c3, t1.* + Sort Key: t1.c1 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c3, t1.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR UPDATE + -> Sort + Output: t2.c1, t2.* + Sort Key: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1, t2.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR UPDATE +(26 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- join two tables with FOR SHARE clause +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> LockRows + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> Sort + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, l.a3, r.a1, r.a2 FROM (SELECT "C 1", c3, ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR SHARE) l (a1, a2, a3) INNER JOIN (SELECT "C 1", ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1") r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Merge Join + Output: t1.c1, t1.c3, t1.*, t2.c1, t2.* + Merge Cond: (t1.c1 = t2.c1) + -> Sort + Output: t1.c1, t1.c3, t1.* + Sort Key: t1.c1 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c3, t1.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR SHARE + -> Sort + Output: t2.c1, t2.* + Sort Key: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1, t2.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" +(26 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE; + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> LockRows + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + -> Sort + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3, t1.*, t2.* + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, l.a3, r.a1, r.a2 FROM (SELECT "C 1", c3, ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR SHARE) l (a1, a2, a3) INNER JOIN (SELECT "C 1", ROW("C 1", c2, c3, c4, c5, c6, c7, c8) FROM "S 1"."T 1" FOR SHARE) r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Merge Join + Output: t1.c1, t1.c3, t1.*, t2.c1, t2.* + Merge Cond: (t1.c1 = t2.c1) + -> Sort + Output: t1.c1, t1.c3, t1.* + Sort Key: t1.c1 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c3, t1.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR SHARE + -> Sort + Output: t2.c1, t2.* + Sort Key: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1, t2.* + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" FOR SHARE +(26 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- join in CTE +EXPLAIN (COSTS false, VERBOSE) +WITH t (c1_1, c1_3, c2_1) AS (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t.c1_1, t.c2_1, t.c1_3 + CTE t + -> Foreign Scan + Output: t1.c1, t1.c3, t2.c1 + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, r.a1 FROM (SELECT "C 1", c3 FROM "S 1"."T 1") l (a1, a2) INNER JOIN (SELECT "C 1" FROM "S 1"."T 1") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Sort + Output: t.c1_1, t.c2_1, t.c1_3 + Sort Key: t.c1_3, t.c1_1 + -> CTE Scan on t + Output: t.c1_1, t.c2_1, t.c1_3 +(12 rows) + +WITH t (c1_1, c1_3, c2_1) AS (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10; + c1_1 | c2_1 +------+------ + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- ctid with whole-row reference +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3 + -> Sort + Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3 + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3 + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, l.a3, l.a4, r.a1 FROM (SELECT ctid, ROW("C 1", c2, c3, c4, c5, c6, c7, c8), "C 1", c3 FROM "S 1"."T 1") l (a1, a2, a3, a4) INNER JOIN (SELECT ROW("C 1", c2, c3, c4, c5, c6, c7, c8), "C 1" FROM "S 1"."T 1") r (a1, a2) ON (TRUE) WHERE ((l.a3 = r.a2)) +(9 rows) + +SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + ctid | t1 | t2 | c1 +--------+--------------------------------------------------------------------------------------------+--------------------------------------------------------------------------------------------+----- + (1,4) | (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo) | (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo) | 101 + (1,5) | (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo) | (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo) | 102 + (1,6) | (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo) | (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo) | 103 + (1,7) | (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo) | (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo) | 104 + (1,8) | (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo) | (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo) | 105 + (1,9) | (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo) | (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo) | 106 + (1,10) | (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo) | (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo) | 107 + (1,11) | (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo) | (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo) | 108 + (1,12) | (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo) | (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo) | 109 + (1,13) | (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo) | (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo) | 110 +(10 rows) + +-- SEMI JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +---------------------------------------------------------------------------------- + Limit + Output: t1.c1 + -> Merge Semi Join + Output: t1.c1 + Merge Cond: (t1.c1 = t2.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 + -> Materialize + Output: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1 + Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC +(13 rows) + +SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10; + c1 +----- + 101 + 102 + 103 + 104 + 105 + 106 + 107 + 108 + 109 + 110 +(10 rows) + +-- ANTI JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +---------------------------------------------------------------------------- + Limit + Output: t1.c1 + -> Merge Anti Join + Output: t1.c1 + Merge Cond: (t1.c1 = t2.c2) + -> Foreign Scan on public.ft1 t1 + Output: t1.c1 + Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC + -> Materialize + Output: t2.c2 + -> Foreign Scan on public.ft2 t2 + Output: t2.c2 + Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC +(13 rows) + +SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10; + c1 +----- + 110 + 111 + 112 + 113 + 114 + 115 + 116 + 117 + 118 + 119 +(10 rows) + +-- CROSS JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +--------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Nested Loop + Output: t1.c1, t2.c1 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1 + Remote SQL: SELECT "C 1" FROM "S 1"."T 1" + -> Materialize + Output: t2.c1 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1 + Remote SQL: SELECT "C 1" FROM "S 1"."T 1" +(15 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + c1 | c1 +----+----- + 1 | 101 + 1 | 102 + 1 | 103 + 1 | 104 + 1 | 105 + 1 | 106 + 1 | 107 + 1 | 108 + 1 | 109 + 1 | 110 +(10 rows) + +-- different server, not pushed down. No result expected. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +---------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Merge Join + Output: t1.c1, t2.c1 + Merge Cond: (t2.c1 = t1.c1) + -> Foreign Scan on public.ft6 t2 + Output: t2.c1, t2.c2, t2.c3 + Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC + -> Materialize + Output: t1.c1, t1.c2, t1.c3 + -> Foreign Scan on public.ft5 t1 + Output: t1.c1, t1.c2, t1.c3 + Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC +(13 rows) + +SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + c1 | c1 +----+---- +(0 rows) + +-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS +-- JOIN since c8 in both tables has same value. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Merge Left Join + Output: t1.c1, t2.c1 + Merge Cond: (t1.c8 = t2.c8) + -> Sort + Output: t1.c1, t1.c8 + Sort Key: t1.c8 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c8 + Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1" + -> Sort + Output: t2.c1, t2.c8 + Sort Key: t2.c8 + -> Foreign Scan on public.ft2 t2 + Output: t2.c1, t2.c8 + Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1" +(20 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; + c1 | c1 +----+----- + 1 | 101 + 1 | 102 + 1 | 103 + 1 | 104 + 1 | 105 + 1 | 106 + 1 | 107 + 1 | 108 + 1 | 109 + 1 | 110 +(10 rows) + +-- unsafe conditions on one side (c8 has a UDT), not pushed down. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +----------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3 + -> Sort + Output: t1.c1, t2.c1, t1.c3 + Sort Key: t1.c3, t1.c1 + -> Hash Right Join + Output: t1.c1, t2.c1, t1.c3 + Hash Cond: (t2.c1 = t1.c1) + -> Foreign Scan on public.ft2 t2 + Output: t2.c1 + Remote SQL: SELECT "C 1" FROM "S 1"."T 1" + -> Hash + Output: t1.c1, t1.c3 + -> Foreign Scan on public.ft1 t1 + Output: t1.c1, t1.c3 + Filter: (t1.c8 = 'foo'::user_enum) + Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1" +(17 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- join where unsafe to pushdown condition in WHERE clause has a column not +-- in the SELECT clause. In this test unsafe clause needs to have column +-- references from both joining sides so that the clause is not pushed down +-- into one of the joining sides. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1, t1.c3 + -> Sort + Output: t1.c1, t2.c1, t1.c3 + Sort Key: t1.c3, t1.c1 + -> Foreign Scan + Output: t1.c1, t2.c1, t1.c3 + Filter: (t1.c8 = t2.c8) + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, l.a2, r.a1, l.a3, r.a2 FROM (SELECT "C 1", c3, c8 FROM "S 1"."T 1") l (a1, a2, a3) INNER JOIN (SELECT "C 1", c8 FROM "S 1"."T 1") r (a1, a2) ON (TRUE) WHERE ((l.a1 = r.a1)) +(10 rows) + +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; + c1 | c1 +-----+----- + 101 | 101 + 102 | 102 + 103 | 103 + 104 | 104 + 105 | 105 + 106 | 106 + 107 | 107 + 108 | 108 + 109 | 109 + 110 | 110 +(10 rows) + +-- Aggregate after UNION, for testing setrefs +EXPLAIN (COSTS false, VERBOSE) +SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10; + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, (avg((t1.c1 + t2.c1))) + -> Sort + Output: t1.c1, (avg((t1.c1 + t2.c1))) + Sort Key: t1.c1 + -> HashAggregate + Output: t1.c1, avg((t1.c1 + t2.c1)) + Group Key: t1.c1 + -> HashAggregate + Output: t1.c1, t2.c1 + Group Key: t1.c1, t2.c1 + -> Append + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT "C 1" FROM "S 1"."T 1") l (a1) INNER JOIN (SELECT "C 1" FROM "S 1"."T 1") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) + -> Foreign Scan + Output: t1_1.c1, t2_1.c1 + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT "C 1" FROM "S 1"."T 1") l (a1) INNER JOIN (SELECT "C 1" FROM "S 1"."T 1") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) +(20 rows) + +SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10; + t1c1 | avg +------+---------------------- + 101 | 202.0000000000000000 + 102 | 204.0000000000000000 + 103 | 206.0000000000000000 + 104 | 208.0000000000000000 + 105 | 210.0000000000000000 + 106 | 212.0000000000000000 + 107 | 214.0000000000000000 + 108 | 216.0000000000000000 + 109 | 218.0000000000000000 + 110 | 220.0000000000000000 +(10 rows) + +-- join with lateral reference +EXPLAIN (COSTS false, VERBOSE) +SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + Limit + Output: t1."C 1" + -> Nested Loop + Output: t1."C 1" + -> Index Scan using t1_pkey on "S 1"."T 1" t1 + Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8 + -> HashAggregate + Output: t2.c1, t3.c1 + Group Key: t2.c1, t3.c1 + -> Foreign Scan + Output: t2.c1, t3.c1 + Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT "C 1" FROM "S 1"."T 1" WHERE ((c2 = $1::integer))) l (a1) INNER JOIN (SELECT "C 1" FROM "S 1"."T 1") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) +(13 rows) + +SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10; + C 1 +----- + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 +(10 rows) + +-- create another user for permission, user mapping, effective user tests +CREATE USER view_owner; +-- grant privileges on ft4 and ft5 to view_owner +GRANT ALL ON ft4 TO view_owner; +GRANT ALL ON ft5 TO view_owner; +-- prepare statement with current session user +PREPARE join_stmt AS SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +EXPLAIN (COSTS OFF, VERBOSE) EXECUTE join_stmt; + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, t2.c1 + -> Sort + Output: t1.c1, t2.c1 + Sort Key: t1.c1, t2.c1 + -> Foreign Scan + Output: t1.c1, t2.c1 + Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 3") l (a1) LEFT JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON ((l.a1 = r.a1)) +(9 rows) + +EXECUTE join_stmt; + c1 | c1 +----+---- + 22 | + 24 | 24 + 26 | + 28 | + 30 | 30 + 32 | + 34 | + 36 | 36 + 38 | + 40 | +(10 rows) + +-- change the session user to view_owner and execute the statement. Because of +-- change in session user, the plan should get invalidated and created again. +-- While creating the plan, it should throw error since there is no user mapping +-- available for view_owner. +SET SESSION ROLE view_owner; +EXPLAIN (COSTS OFF, VERBOSE) EXECUTE join_stmt; +ERROR: user mapping not found for "view_owner" +EXECUTE join_stmt; +ERROR: user mapping not found for "view_owner" +RESET ROLE; +DEALLOCATE join_stmt; +CREATE VIEW v_ft5 AS SELECT * FROM ft5; +-- change owner of v_ft5 to view_owner so that the effective user for scan on +-- ft5 is view_owner and not the current user. +ALTER VIEW v_ft5 OWNER TO view_owner; +-- create a public user mapping for loopback server +-- drop user mapping for current_user. +DROP USER MAPPING FOR CURRENT_USER SERVER loopback; +CREATE USER MAPPING FOR PUBLIC SERVER loopback; +-- different effective user for permission check, but same user mapping for the +-- joining sides, join pushed down, no result expected. +PREPARE join_stmt AS SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN v_ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +EXPLAIN (COSTS false, VERBOSE) EXECUTE join_stmt; + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Limit + Output: t1.c1, ft5.c1 + -> Sort + Output: t1.c1, ft5.c1 + Sort Key: t1.c1 + -> Foreign Scan + Output: t1.c1, ft5.c1 + Relations: (public.ft5 t1) INNER JOIN (public.ft5) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c1 FROM "S 1"."T 4") l (a1) INNER JOIN (SELECT c1 FROM "S 1"."T 4") r (a1) ON (TRUE) WHERE ((l.a1 = r.a1)) +(9 rows) + +EXECUTE join_stmt; + c1 | c1 +----+---- +(0 rows) + +-- create user mapping for view_owner and execute the prepared statement +-- the join should not be pushed down since joining relations now use two +-- different user mappings +CREATE USER MAPPING FOR view_owner SERVER loopback; +EXPLAIN (COSTS false, VERBOSE) EXECUTE join_stmt; + QUERY PLAN +---------------------------------------------------------------------------- + Limit + Output: t1.c1, ft5.c1 + -> Merge Join + Output: t1.c1, ft5.c1 + Merge Cond: (t1.c1 = ft5.c1) + -> Foreign Scan on public.ft5 t1 + Output: t1.c1, t1.c2, t1.c3 + Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC + -> Materialize + Output: ft5.c1, ft5.c2, ft5.c3 + -> Foreign Scan on public.ft5 + Output: ft5.c1, ft5.c2, ft5.c3 + Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC +(13 rows) + +EXECUTE join_stmt; + c1 | c1 +----+---- +(0 rows) + +-- recreate the dropped user mapping for further tests +CREATE USER MAPPING FOR CURRENT_USER SERVER loopback; +DROP USER MAPPING FOR PUBLIC SERVER loopback; +-- =================================================================== -- parameterized queries -- =================================================================== -- simple join PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2; EXPLAIN (VERBOSE, COSTS false) EXECUTE st1(1, 2); - QUERY PLAN --------------------------------------------------------------------- - Nested Loop + QUERY PLAN +--------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + Foreign Scan Output: t1.c3, t2.c3 - -> Foreign Scan on public.ft1 t1 - Output: t1.c3 - Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 1)) - -> Foreign Scan on public.ft2 t2 - Output: t2.c3 - Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 2)) -(8 rows) + Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 1))) l (a1) INNER JOIN (SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 2))) r (a1) ON (TRUE) +(4 rows) EXECUTE st1(1, 1); c3 | c3 -------+------- 00001 | 00001 (1 row) EXECUTE st1(101, 101); c3 | c3 -------+------- @@ -1128,20 +2084,23 @@ SELECT f_test(100); (1 row) DROP FUNCTION f_test(int); -- =================================================================== -- conversion error -- =================================================================== ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int; SELECT * FROM ft1 WHERE c1 = 1; -- ERROR ERROR: invalid input syntax for integer: "foo" CONTEXT: column "c8" of foreign table "ft1" +SELECT ft1.c1, ft2.c2, ft1.c8 FROM ft1, ft2 WHERE ft1.c1 = ft2.c1 AND ft1.c1 = 1; -- ERROR +ERROR: invalid input syntax for integer: "foo" +CONTEXT: column "c8" of foreign table "ft1" ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum; -- =================================================================== -- subtransaction -- + local/remote error doesn't break cursor -- =================================================================== BEGIN; DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1; FETCH c; c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 ----+----+-------+------------------------------+--------------------------+----+------------+----- @@ -1418,36 +2377,40 @@ UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo 1007 | 507 | 0000700007_update7 | | | | ft2 | 1017 | 507 | 0001700017_update7 | | | | ft2 | (102 rows) EXPLAIN (verbose, costs off) UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; - QUERY PLAN -------------------------------------------------------------------------------------------------------------------------------------------------------------------- + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Update on public.ft2 Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c3 = $3, c7 = $4 WHERE ctid = $1 - -> Hash Join + -> Foreign Scan Output: ft2.c1, (ft2.c2 + 500), NULL::integer, (ft2.c3 || '_update9'::text), ft2.c4, ft2.c5, ft2.c6, 'ft2 '::character(10), ft2.c8, ft2.ctid, ft1.* - Hash Cond: (ft2.c2 = ft1.c1) - -> Foreign Scan on public.ft2 - Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c8, ft2.ctid - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c8, ctid FROM "S 1"."T 1" FOR UPDATE - -> Hash - Output: ft1.*, ft1.c1 - -> Foreign Scan on public.ft1 + Relations: (public.ft2) INNER JOIN (public.ft1) + Remote SQL: SELECT l.a1, l.a2, l.a3, l.a4, l.a5, l.a6, l.a7, l.a8, r.a1 FROM (SELECT "C 1", c2, c3, c4, c5, c6, c8, ctid FROM "S 1"."T 1" FOR UPDATE) l (a1, a2, a3, a4, a5, a6, a7, a8) INNER JOIN (SELECT ROW("C 1", c2, c3, c4, c5, c6, c7, c8), "C 1" FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 9))) r (a1, a2) ON (TRUE) WHERE ((l.a2 = r.a2)) + -> Hash Join + Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c8, ft2.ctid, ft1.* + Hash Cond: (ft2.c2 = ft1.c1) + -> Foreign Scan on public.ft2 + Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c8, ft2.ctid + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c8, ctid FROM "S 1"."T 1" FOR UPDATE + -> Hash Output: ft1.*, ft1.c1 - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 9)) -(13 rows) + -> Foreign Scan on public.ft1 + Output: ft1.*, ft1.c1 + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 9)) +(17 rows) UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; EXPLAIN (verbose, costs off) DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; QUERY PLAN ---------------------------------------------------------------------------------------- Delete on public.ft2 Output: c1, c4 Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c4 @@ -1559,36 +2522,40 @@ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; 975 | Tue Mar 17 00:00:00 1970 PST 985 | Fri Mar 27 00:00:00 1970 PST 995 | Mon Apr 06 00:00:00 1970 PST 1005 | 1015 | 1105 | (103 rows) EXPLAIN (verbose, costs off) DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; - QUERY PLAN ----------------------------------------------------------------------------------------------------------------------- + QUERY PLAN +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Delete on public.ft2 Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 - -> Hash Join + -> Foreign Scan Output: ft2.ctid, ft1.* - Hash Cond: (ft2.c2 = ft1.c1) - -> Foreign Scan on public.ft2 - Output: ft2.ctid, ft2.c2 - Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" FOR UPDATE - -> Hash - Output: ft1.*, ft1.c1 - -> Foreign Scan on public.ft1 + Relations: (public.ft2) INNER JOIN (public.ft1) + Remote SQL: SELECT l.a1, r.a1 FROM (SELECT ctid, c2 FROM "S 1"."T 1" FOR UPDATE) l (a1, a2) INNER JOIN (SELECT ROW("C 1", c2, c3, c4, c5, c6, c7, c8), "C 1" FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 2))) r (a1, a2) ON (TRUE) WHERE ((l.a2 = r.a2)) + -> Hash Join + Output: ft2.ctid, ft1.* + Hash Cond: (ft2.c2 = ft1.c1) + -> Foreign Scan on public.ft2 + Output: ft2.ctid, ft2.c2 + Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" FOR UPDATE + -> Hash Output: ft1.*, ft1.c1 - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 2)) -(13 rows) + -> Foreign Scan on public.ft1 + Output: ft1.*, ft1.c1 + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 2)) +(17 rows) DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1; c1 | c2 | c3 | c4 ------+-----+--------------------+------------------------------ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST @@ -3944,10 +4911,13 @@ ERROR: type "public.Colors" does not exist LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col') ^ QUERY: CREATE FOREIGN TABLE t5 ( c1 integer OPTIONS (column_name 'c1'), c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C", "Col" public."Colors" OPTIONS (column_name 'Col') ) SERVER loopback OPTIONS (schema_name 'import_source', table_name 't5'); CONTEXT: importing foreign table "t5" ROLLBACK; +-- Cleanup +DROP OWNED BY view_owner; +DROP USER view_owner; diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index 2ab85f6..af7dcc5 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -21,23 +21,23 @@ #include "commands/vacuum.h" #include "foreign/fdwapi.h" #include "funcapi.h" #include "miscadmin.h" #include "nodes/makefuncs.h" #include "nodes/nodeFuncs.h" #include "optimizer/cost.h" #include "optimizer/pathnode.h" #include "optimizer/paths.h" #include "optimizer/planmain.h" -#include "optimizer/prep.h" #include "optimizer/restrictinfo.h" #include "optimizer/var.h" +#include "optimizer/tlist.h" #include "parser/parsetree.h" #include "utils/builtins.h" #include "utils/guc.h" #include "utils/lsyscache.h" #include "utils/memutils.h" #include "utils/rel.h" #include "utils/sampling.h" PG_MODULE_MAGIC; @@ -47,35 +47,39 @@ PG_MODULE_MAGIC; /* Default CPU cost to process 1 row (above and beyond cpu_tuple_cost). */ #define DEFAULT_FDW_TUPLE_COST 0.01 /* If no remote estimates, assume a sort costs 20% extra */ #define DEFAULT_FDW_SORT_MULTIPLIER 1.2 /* * Indexes of FDW-private information stored in fdw_private lists. * * We store various information in ForeignScan.fdw_private to pass it from - * planner to executor. Currently we store: - * - * 1) SELECT statement text to be sent to the remote server - * 2) Integer list of attribute numbers retrieved by the SELECT + * planner to executor. * * These items are indexed with the enum FdwScanPrivateIndex, so an item * can be fetched with list_nth(). For example, to get the SELECT statement: * sql = strVal(list_nth(fdw_private, FdwScanPrivateSelectSql)); */ enum FdwScanPrivateIndex { /* SQL statement to execute remotely (as a String node) */ FdwScanPrivateSelectSql, /* Integer list of attribute numbers retrieved by the SELECT */ - FdwScanPrivateRetrievedAttrs + FdwScanPrivateRetrievedAttrs, + /* Oid of user mapping to be used while connecting to the foreign server */ + FdwScanPrivateUserMappingOid, + /* + * String describing join i.e. names of relations being joined and types of + * join, added when the scan is join + */ + FdwScanPrivateRelations, }; /* * Similarly, this enum describes what's kept in the fdw_private list for * a ModifyTable node referencing a postgres_fdw foreign table. We store: * * 1) INSERT/UPDATE/DELETE statement text to be sent to the remote server * 2) Integer list of target attribute numbers for INSERT/UPDATE * (NIL for a DELETE) * 3) Boolean flag showing if the remote query has a RETURNING clause @@ -91,21 +95,24 @@ enum FdwModifyPrivateIndex FdwModifyPrivateHasReturning, /* Integer list of attribute numbers retrieved by RETURNING */ FdwModifyPrivateRetrievedAttrs }; /* * Execution state of a foreign scan using postgres_fdw. */ typedef struct PgFdwScanState { - Relation rel; /* relcache entry for the foreign table */ + Relation rel; /* relcache entry for the foreign table. + * NULL for a foreign join scan. + */ + TupleDesc tupdesc; /* tuple descriptor of scan */ AttInMetadata *attinmeta; /* attribute datatype conversion metadata */ /* extracted fdw_private data */ char *query; /* text of SELECT command */ List *retrieved_attrs; /* list of retrieved attribute numbers */ /* for remote query execution */ PGconn *conn; /* connection for the scan */ unsigned int cursor_number; /* quasi-unique ID for my cursor */ bool cursor_exists; /* have we created the cursor? */ @@ -177,22 +184,29 @@ typedef struct PgFdwAnalyzeState /* working memory contexts */ MemoryContext anl_cxt; /* context for per-analyze lifespan data */ MemoryContext temp_cxt; /* context for per-tuple temporary data */ } PgFdwAnalyzeState; /* * Identify the attribute where data conversion fails. */ typedef struct ConversionLocation { - Relation rel; /* foreign table's relcache entry */ + Relation rel; /* foreign table's relcache entry. */ AttrNumber cur_attno; /* attribute number being processed, or 0 */ + /* + * In case of foreign join push down, fdw_scan_tlist is used to identify the + * Var node corresponding to the error location and fsstate->ss.ps.state + * gives access to the RTEs of corresponding relation to get the relation + * name and attribute name. + */ + ForeignScanState *fsstate; } ConversionLocation; /* Callback argument for ec_member_matches_foreign */ typedef struct { Expr *current; /* current expr, or NULL if not yet found */ List *already_used; /* expressions already dealt with */ } ec_member_foreign_arg; /* @@ -252,20 +266,28 @@ static void postgresExplainForeignScan(ForeignScanState *node, static void postgresExplainForeignModify(ModifyTableState *mtstate, ResultRelInfo *rinfo, List *fdw_private, int subplan_index, ExplainState *es); static bool postgresAnalyzeForeignTable(Relation relation, AcquireSampleRowsFunc *func, BlockNumber *totalpages); static List *postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid); +static void postgresGetForeignJoinPaths(PlannerInfo *root, + RelOptInfo *joinrel, + RelOptInfo *outerrel, + RelOptInfo *innerrel, + JoinType jointype, + JoinPathExtraData *extra); +static bool postgresRecheckForeignScan(ForeignScanState *node, + TupleTableSlot *slot); static List *get_useful_pathkeys_for_relation(PlannerInfo *root, RelOptInfo *rel); static List *get_useful_ecs_for_relation(PlannerInfo *root, RelOptInfo *rel); /* * Helper functions */ static void estimate_path_cost_size(PlannerInfo *root, RelOptInfo *baserel, List *join_conds, @@ -294,23 +316,26 @@ static int postgresAcquireSampleRowsFunc(Relation relation, int elevel, HeapTuple *rows, int targrows, double *totalrows, double *totaldeadrows); static void analyze_row_processor(PGresult *res, int row, PgFdwAnalyzeState *astate); static HeapTuple make_tuple_from_result_row(PGresult *res, int row, Relation rel, AttInMetadata *attinmeta, List *retrieved_attrs, + ForeignScanState *fsstate, MemoryContext temp_context); static void conversion_error_callback(void *arg); - +static bool foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, + JoinType jointype, RelOptInfo *outerrel, RelOptInfo *innerrel, + JoinPathExtraData *extra); /* * Foreign-data wrapper handler function: return a struct with pointers * to my callback routines. */ Datum postgres_fdw_handler(PG_FUNCTION_ARGS) { FdwRoutine *routine = makeNode(FdwRoutine); @@ -326,30 +351,35 @@ postgres_fdw_handler(PG_FUNCTION_ARGS) /* Functions for updating foreign tables */ routine->AddForeignUpdateTargets = postgresAddForeignUpdateTargets; routine->PlanForeignModify = postgresPlanForeignModify; routine->BeginForeignModify = postgresBeginForeignModify; routine->ExecForeignInsert = postgresExecForeignInsert; routine->ExecForeignUpdate = postgresExecForeignUpdate; routine->ExecForeignDelete = postgresExecForeignDelete; routine->EndForeignModify = postgresEndForeignModify; routine->IsForeignRelUpdatable = postgresIsForeignRelUpdatable; + /* Function for EvalPlanQual rechecks */ + routine->RecheckForeignScan = postgresRecheckForeignScan; /* Support functions for EXPLAIN */ routine->ExplainForeignScan = postgresExplainForeignScan; routine->ExplainForeignModify = postgresExplainForeignModify; /* Support functions for ANALYZE */ routine->AnalyzeForeignTable = postgresAnalyzeForeignTable; /* Support functions for IMPORT FOREIGN SCHEMA */ routine->ImportForeignSchema = postgresImportForeignSchema; + /* Support functions for join push-down */ + routine->GetForeignJoinPaths = postgresGetForeignJoinPaths; + PG_RETURN_POINTER(routine); } /* * postgresGetForeignRelSize * Estimate # of rows and width of the result of the scan * * We should consider the effect of all baserestrictinfo clauses here, but * not any join clauses. */ @@ -361,20 +391,23 @@ postgresGetForeignRelSize(PlannerInfo *root, PgFdwRelationInfo *fpinfo; ListCell *lc; /* * We use PgFdwRelationInfo to pass various information to subsequent * functions. */ fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo)); baserel->fdw_private = (void *) fpinfo; + /* Base foreign tables need to be push down always. */ + fpinfo->pushdown_safe = true; + /* Look up foreign-table catalog info. */ fpinfo->table = GetForeignTable(foreigntableid); fpinfo->server = GetForeignServer(fpinfo->table->serverid); /* * Extract user-settable option values. Note that per-table setting of * use_remote_estimate overrides per-server setting. */ fpinfo->use_remote_estimate = false; fpinfo->fdw_startup_cost = DEFAULT_FDW_STARTUP_COST; @@ -928,37 +961,59 @@ postgresGetForeignPaths(PlannerInfo *root, add_path(baserel, (Path *) path); } } /* * postgresGetForeignPlan * Create ForeignScan plan node which implements selected best path */ static ForeignScan * postgresGetForeignPlan(PlannerInfo *root, - RelOptInfo *baserel, + RelOptInfo *foreignrel, Oid foreigntableid, ForeignPath *best_path, List *tlist, List *scan_clauses, Plan *outer_plan) { - PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) baserel->fdw_private; - Index scan_relid = baserel->relid; + PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private; + Index scan_relid; List *fdw_private; List *remote_conds = NIL; List *remote_exprs = NIL; List *local_exprs = NIL; List *params_list = NIL; List *retrieved_attrs; StringInfoData sql; ListCell *lc; + List *fdw_scan_tlist = NIL; + StringInfoData relations; + + /* + * For base relations, set scan_relid as the relid of the relation. For other + * kinds of relations set it to 0. + */ + if (foreignrel->reloptkind == RELOPT_BASEREL || + foreignrel->reloptkind == RELOPT_OTHER_MEMBER_REL) + scan_relid = foreignrel->relid; + else + { + scan_relid = 0; + /* + * create_scan_plan() and create_foreignscan_plan() pass + * 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. + */ + Assert(!scan_clauses); + } /* * Separate the scan_clauses into those that can be executed remotely and * those that can't. baserestrictinfo clauses that were previously * determined to be safe or unsafe by classifyConditions are shown in * fpinfo->remote_conds and fpinfo->local_conds. Anything else in the * scan_clauses list will be a join clause, which we have to check for * remote-safety. * * Note: the join clauses we see here should be the exact same ones @@ -982,103 +1037,135 @@ postgresGetForeignPlan(PlannerInfo *root, if (rinfo->pseudoconstant) continue; if (list_member_ptr(fpinfo->remote_conds, rinfo)) { remote_conds = lappend(remote_conds, rinfo); remote_exprs = lappend(remote_exprs, rinfo->clause); } else if (list_member_ptr(fpinfo->local_conds, rinfo)) local_exprs = lappend(local_exprs, rinfo->clause); - else if (is_foreign_expr(root, baserel, rinfo->clause)) + else if (is_foreign_expr(root, foreignrel, rinfo->clause)) { remote_conds = lappend(remote_conds, rinfo); remote_exprs = lappend(remote_exprs, rinfo->clause); } else local_exprs = lappend(local_exprs, rinfo->clause); } + if (foreignrel->reloptkind == RELOPT_JOINREL) + { + /* For a join relation, get the conditions from fdw_private structure */ + remote_conds = fpinfo->remote_conds; + 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); + } + /* * Build the query string to be sent for execution, and identify - * expressions to be sent as parameters. + * expressions to be sent as parameters. If the relation to scan is a join + * relation, receive constructed relations string. */ initStringInfo(&sql); - deparseSelectStmtForRel(&sql, root, baserel, remote_conds, + if (foreignrel->reloptkind == RELOPT_JOINREL) + initStringInfo(&relations); + deparseSelectStmtForRel(&sql, root, foreignrel, remote_conds, best_path->path.pathkeys, &retrieved_attrs, - ¶ms_list); + ¶ms_list, fdw_scan_tlist, + foreignrel->reloptkind == RELOPT_JOINREL ? &relations : + NULL); + /* * Build the fdw_private list that will be available to the executor. - * Items in the list must match enum FdwScanPrivateIndex, above. + * Items in the list must match order in enum FdwScanPrivateIndex. */ - fdw_private = list_make2(makeString(sql.data), - retrieved_attrs); + fdw_private = list_make3(makeString(sql.data), + retrieved_attrs, + makeInteger(foreignrel->umid)); + if (foreignrel->reloptkind == RELOPT_JOINREL) + fdw_private = lappend(fdw_private, makeString(relations.data)); /* - * Create the ForeignScan node from target list, filtering expressions, - * remote parameter expressions, and FDW private information. + * Create the ForeignScan node for the given relation. * * Note that the remote parameter expressions are stored in the fdw_exprs * field of the finished plan node; we can't keep them in private state * because then they wouldn't be subject to later planner processing. */ return make_foreignscan(tlist, local_exprs, scan_relid, params_list, fdw_private, - NIL, /* no custom tlist */ + fdw_scan_tlist, remote_exprs, outer_plan); } /* * postgresBeginForeignScan * Initiate an executor scan of a foreign PostgreSQL table. */ static void postgresBeginForeignScan(ForeignScanState *node, int eflags) { ForeignScan *fsplan = (ForeignScan *) node->ss.ps.plan; EState *estate = node->ss.ps.state; PgFdwScanState *fsstate; - RangeTblEntry *rte; - Oid userid; - ForeignTable *table; UserMapping *user; int numParams; int i; ListCell *lc; /* * Do nothing in EXPLAIN (no ANALYZE) case. node->fdw_state stays NULL. */ if (eflags & EXEC_FLAG_EXPLAIN_ONLY) return; /* * We'll save private state in node->fdw_state. */ fsstate = (PgFdwScanState *) palloc0(sizeof(PgFdwScanState)); node->fdw_state = (void *) fsstate; /* - * Identify which user to do the remote access as. This should match what - * ExecCheckRTEPerms() does. + * Obtain the foreign server where to connect and user mapping to use for + * connection. For base relations we obtain this information from catalogs. + * For join relations, this information is frozen at the time of planning to + * ensure that the join is safe to pushdown. In case the information goes + * stale between planning and execution, plan will be invalidated and + * replanned. */ - rte = rt_fetch(fsplan->scan.scanrelid, estate->es_range_table); - userid = rte->checkAsUser ? rte->checkAsUser : GetUserId(); + if (fsplan->scan.scanrelid > 0) + { + ForeignTable *table; + /* + * Identify which user to do the remote access as. This should match what + * ExecCheckRTEPerms() does. + */ + RangeTblEntry *rte = rt_fetch(fsplan->scan.scanrelid, estate->es_range_table); + Oid userid = rte->checkAsUser ? rte->checkAsUser : GetUserId(); + fsstate->rel = node->ss.ss_currentRelation; + table = GetForeignTable(RelationGetRelid(fsstate->rel)); - /* Get info about foreign table. */ - fsstate->rel = node->ss.ss_currentRelation; - table = GetForeignTable(RelationGetRelid(fsstate->rel)); - user = GetUserMapping(userid, table->serverid); + user = GetUserMapping(userid, table->serverid); + } + else + { + Oid umid = intVal(list_nth(fsplan->fdw_private, FdwScanPrivateUserMappingOid)); + user = GetUserMappingById(umid); + Assert(fsplan->fs_server == user->serverid); + } /* * Get connection to the foreign server. Connection manager will * establish new connection if necessary. */ fsstate->conn = GetConnection(user, false); /* Assign a unique ID for my cursor */ fsstate->cursor_number = GetCursorNumber(fsstate->conn); fsstate->cursor_exists = false; @@ -1094,22 +1181,30 @@ postgresBeginForeignScan(ForeignScanState *node, int eflags) "postgres_fdw tuple data", ALLOCSET_DEFAULT_MINSIZE, ALLOCSET_DEFAULT_INITSIZE, ALLOCSET_DEFAULT_MAXSIZE); fsstate->temp_cxt = AllocSetContextCreate(estate->es_query_cxt, "postgres_fdw temporary data", ALLOCSET_SMALL_MINSIZE, ALLOCSET_SMALL_INITSIZE, ALLOCSET_SMALL_MAXSIZE); - /* Get info we'll need for input data conversion. */ - fsstate->attinmeta = TupleDescGetAttInMetadata(RelationGetDescr(fsstate->rel)); + /* + * Get info we'll need for converting data fetched from the foreign server + * into local representation and error reporting during that process. + */ + if (fsplan->scan.scanrelid > 0) + fsstate->tupdesc = RelationGetDescr(fsstate->rel); + else + fsstate->tupdesc = node->ss.ss_ScanTupleSlot->tts_tupleDescriptor; + + fsstate->attinmeta = TupleDescGetAttInMetadata(fsstate->tupdesc); /* Prepare for output conversion of parameters used in remote query. */ numParams = list_length(fsplan->fdw_exprs); fsstate->numParams = numParams; fsstate->param_flinfo = (FmgrInfo *) palloc0(sizeof(FmgrInfo) * numParams); i = 0; foreach(lc, fsplan->fdw_exprs) { Node *param_expr = (Node *) lfirst(lc); @@ -1814,32 +1909,75 @@ postgresIsForeignRelUpdatable(Relation rel) } /* * Currently "updatable" means support for INSERT, UPDATE and DELETE. */ return updatable ? (1 << CMD_INSERT) | (1 << CMD_UPDATE) | (1 << CMD_DELETE) : 0; } /* + * postgresRecheckForeignScan + * Execute a local join execution plan for a foreign join + */ +static bool +postgresRecheckForeignScan(ForeignScanState *node, TupleTableSlot *slot) +{ + Index scanrelid = ((Scan *) node->ss.ps.plan)->scanrelid; + PlanState *outerPlan = outerPlanState(node); + TupleTableSlot *result; + + /* For base foreign relations, it suffices to set fdw_recheck_quals */ + if (scanrelid > 0) + return true; + + Assert(outerPlan != NULL); + + /* Execute a local join execution plan */ + result = ExecProcNode(outerPlan); + if (TupIsNull(result)) + return false; + + /* Store result in the given slot */ + ExecCopySlot(slot, result); + + return true; +} + +/* * postgresExplainForeignScan * Produce extra output for EXPLAIN of a ForeignScan on a foreign table */ static void postgresExplainForeignScan(ForeignScanState *node, ExplainState *es) { List *fdw_private; char *sql; + char *relations; + + fdw_private = ((ForeignScan *) node->ss.ps.plan)->fdw_private; + + /* + * Add names of relation handled by the foreign scan when the scan is a + * join + */ + if (list_length(fdw_private) > FdwScanPrivateRelations) + { + relations = strVal(list_nth(fdw_private, FdwScanPrivateRelations)); + ExplainPropertyText("Relations", relations, es); + } + /* + * Add remote query, when VERBOSE option is specified. + */ if (es->verbose) { - fdw_private = ((ForeignScan *) node->ss.ps.plan)->fdw_private; sql = strVal(list_nth(fdw_private, FdwScanPrivateSelectSql)); ExplainPropertyText("Remote SQL", sql, es); } } /* * postgresExplainForeignModify * Produce extra output for EXPLAIN of a ModifyTable on a foreign table */ static void @@ -1854,161 +1992,245 @@ postgresExplainForeignModify(ModifyTableState *mtstate, char *sql = strVal(list_nth(fdw_private, FdwModifyPrivateUpdateSql)); ExplainPropertyText("Remote SQL", sql, es); } } /* * estimate_path_cost_size - * Get cost and size estimates for a foreign scan + * Get cost and size estimates for a foreign scan on given foreign relation + * either a base relation or a join between 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. * - * We assume that all the baserestrictinfo clauses will be applied, plus - * any join clauses listed in join_conds. + * The function returns the cost and size estimates in p_row, p_width, + * p_startup_cost and p_total_cost variables. */ static void estimate_path_cost_size(PlannerInfo *root, - RelOptInfo *baserel, - List *join_conds, + RelOptInfo *foreignrel, + List *param_join_conds, List *pathkeys, double *p_rows, int *p_width, Cost *p_startup_cost, Cost *p_total_cost) { - PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) baserel->fdw_private; + PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) foreignrel->fdw_private; double rows; double retrieved_rows; int width; Cost startup_cost; Cost total_cost; Cost run_cost; Cost cpu_per_tuple; /* * If the table or the server is configured to use remote estimates, * connect to the foreign server and execute EXPLAIN to estimate the * number of rows selected by the restriction+join clauses. Otherwise, * estimate rows using whatever statistics we have locally, in a way * similar to ordinary tables. */ if (fpinfo->use_remote_estimate) { - List *remote_join_conds; - List *local_join_conds; + List *remote_param_join_conds; + List *local_param_join_conds; StringInfoData sql; - List *retrieved_attrs; PGconn *conn; Selectivity local_sel; QualCost local_cost; + List *fdw_scan_tlist = NIL; List *remote_conds; /* - * join_conds might contain both clauses that are safe to send across, + * param_join_conds might contain both clauses that are safe to send across, * and clauses that aren't. */ - classifyConditions(root, baserel, join_conds, - &remote_join_conds, &local_join_conds); + classifyConditions(root, foreignrel, param_join_conds, + &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); + else + fdw_scan_tlist = NIL; /* * The complete list of remote conditions includes everything from * baserestrictinfo plus any extra join_conds relevant to this * particular path. */ - remote_conds = list_concat(list_copy(remote_join_conds), + remote_conds = list_concat(list_copy(remote_param_join_conds), fpinfo->remote_conds); /* * Construct EXPLAIN query including the desired SELECT, FROM, and - * WHERE clauses. Params and other-relation Vars are replaced by - * dummy values. + * WHERE clauses. Params and other-relation Vars are replaced by + * dummy values, so don't request params_list. */ initStringInfo(&sql); appendStringInfoString(&sql, "EXPLAIN "); - deparseSelectStmtForRel(&sql, root, baserel, remote_conds, pathkeys, - &retrieved_attrs, NULL); + deparseSelectStmtForRel(&sql, root, foreignrel, remote_conds, pathkeys, + NULL, NULL, fdw_scan_tlist, NULL); /* Get the remote estimate */ conn = GetConnection(fpinfo->user, false); get_remote_estimate(sql.data, conn, &rows, &width, &startup_cost, &total_cost); ReleaseConnection(conn); retrieved_rows = rows; /* Factor in the selectivity of the locally-checked quals */ local_sel = clauselist_selectivity(root, - local_join_conds, - baserel->relid, + local_param_join_conds, + foreignrel->relid, JOIN_INNER, NULL); local_sel *= fpinfo->local_conds_sel; rows = clamp_row_est(rows * local_sel); /* Add in the eval cost of the locally-checked quals */ startup_cost += fpinfo->local_conds_cost.startup; total_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows; - cost_qual_eval(&local_cost, local_join_conds, root); + cost_qual_eval(&local_cost, local_param_join_conds, root); startup_cost += local_cost.startup; total_cost += local_cost.per_tuple * retrieved_rows; } else { /* * We don't support join conditions in this mode (hence, no * parameterized paths can be made). */ - Assert(join_conds == NIL); - - /* Use rows/width estimates made by set_baserel_size_estimates. */ - rows = baserel->rows; - width = baserel->width; + Assert(param_join_conds == NIL); /* - * Back into an estimate of the number of retrieved rows. Just in - * case this is nuts, clamp to at most baserel->tuples. + * Use rows/width estimates made by set_baserel_size_estimates() for + * base foreign relations and set_joinrel_size_estimates() for join + * between foreign relations. */ + rows = foreignrel->rows; + width = foreignrel->width; + + /* Back into an estimate of the number of retrieved rows. */ retrieved_rows = clamp_row_est(rows / fpinfo->local_conds_sel); - retrieved_rows = Min(retrieved_rows, baserel->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 * baserel->pages; + if (foreignrel->reloptkind == RELOPT_BASEREL || + foreignrel->reloptkind == RELOPT_OTHER_MEMBER_REL) + { + /* 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 if (foreignrel->reloptkind == RELOPT_JOINREL) + { + PgFdwRelationInfo *fpinfo_i; + PgFdwRelationInfo *fpinfo_o; + QualCost join_cost; + QualCost remote_conds_cost; + double nrows; + + /* For join we expect inner and outer relations set */ + Assert(fpinfo->innerrel && fpinfo->outerrel); - startup_cost += baserel->baserestrictcost.startup; - cpu_per_tuple = cpu_tuple_cost + baserel->baserestrictcost.per_tuple; - run_cost += cpu_per_tuple * baserel->tuples; + fpinfo_i = (PgFdwRelationInfo *) fpinfo->innerrel->fdw_private; + fpinfo_o = (PgFdwRelationInfo *) fpinfo->outerrel->fdw_private; + + /* Estimate of number of rows in cross product */ + nrows = fpinfo_i->rows * fpinfo_o->rows; + /* Clamp retrieved rows estimate to at most size of cross product */ + retrieved_rows = Min(retrieved_rows, nrows); + + /* + * The cost of foreign join is estimated as cost of generating + * rows for the joining relations + cost for applying quals on the + * rows. + */ + + /* Calculate the cost of clauses pushed down the foreign server */ + cost_qual_eval(&remote_conds_cost, fpinfo->remote_conds, root); + /* Calculate the cost of applying join clauses */ + cost_qual_eval(&join_cost, fpinfo->joinclauses, root); + + /* + * Startup cost includes startup cost of joining relations and the + * startup cost for join and other clauses. We do not include the + * startup cost specific to join strategy (e.g. setting up hash + * tables) since we do not know what strategy the foreign server is + * going to use. + */ + startup_cost = fpinfo_i->rel_startup_cost + fpinfo_o->rel_startup_cost; + startup_cost += join_cost.startup; + startup_cost += remote_conds_cost.startup; + startup_cost += fpinfo->local_conds_cost.startup; + + /* Run time cost includes + * 1. Run time cost (total_cost - startup_cost) of relations being + * joined + * 2. Run time cost of applying join clauses on the cross product of + * the joining relations. + * 3. Run time cost of applying pushed down other clauses on the + * result of join + * 4. Run time cost of applying nonpushable other clauses locally + * on the result fetched from the foreign server. + */ + run_cost = fpinfo_i->rel_total_cost - fpinfo_i->rel_startup_cost; + run_cost += fpinfo_o->rel_total_cost - fpinfo_o->rel_startup_cost; + run_cost += nrows * join_cost.per_tuple; + nrows = clamp_row_est(nrows * fpinfo->joinclause_sel); + run_cost += nrows * remote_conds_cost.per_tuple; + run_cost += fpinfo->local_conds_cost.per_tuple * retrieved_rows; + } /* * Without remote estimates, we have no real way to estimate the cost * of generating sorted output. It could be free if the query plan * the remote side would have chosen generates properly-sorted output * anyway, but in most cases it will cost something. Estimate a value * high enough that we won't pick the sorted path when the ordering * isn't locally useful, but low enough that we'll err on the side of * pushing down the ORDER BY clause when it's useful to do so. */ if (pathkeys != NIL) { startup_cost *= DEFAULT_FDW_SORT_MULTIPLIER; run_cost *= DEFAULT_FDW_SORT_MULTIPLIER; } total_cost = startup_cost + run_cost; } /* + * Cache the costs prior to adding the costs for transferring data from the + * foreign server. These costs are useful for costing the join between this + * relation and another foreign relation, when the cost of join can not be + * obtained from the foreign server. + */ + fpinfo->rel_startup_cost = startup_cost; + fpinfo->rel_total_cost = total_cost; + + /* * Add some additional cost factors to account for connection overhead * (fdw_startup_cost), transferring data across the network * (fdw_tuple_cost per retrieved row), and local manipulation of the data * (cpu_tuple_cost per retrieved row). */ startup_cost += fpinfo->fdw_startup_cost; total_cost += fpinfo->fdw_startup_cost; total_cost += fpinfo->fdw_tuple_cost * retrieved_rows; total_cost += cpu_tuple_cost * retrieved_rows; @@ -2230,25 +2452,29 @@ fetch_more_data(ForeignScanState *node) pgfdw_report_error(ERROR, res, conn, false, fsstate->query); /* Convert the data into HeapTuples */ numrows = PQntuples(res); fsstate->tuples = (HeapTuple *) palloc0(numrows * sizeof(HeapTuple)); fsstate->num_tuples = numrows; fsstate->next_tuple = 0; for (i = 0; i < numrows; i++) { + ForeignScan *fsplan = (ForeignScan *)node->ss.ps.plan; + + Assert(IsA(fsplan, ForeignScan)); fsstate->tuples[i] = make_tuple_from_result_row(res, i, fsstate->rel, fsstate->attinmeta, fsstate->retrieved_attrs, + node, fsstate->temp_cxt); } /* Update fetch_ct_2 */ if (fsstate->fetch_ct_2 < 2) fsstate->fetch_ct_2++; /* Must be EOF if we didn't get as many tuples as we asked for. */ fsstate->eof_reached = (numrows < fetch_size); @@ -2453,20 +2679,21 @@ store_returning_result(PgFdwModifyState *fmstate, TupleTableSlot *slot, PGresult *res) { PG_TRY(); { HeapTuple newtup; newtup = make_tuple_from_result_row(res, 0, fmstate->rel, fmstate->attinmeta, fmstate->retrieved_attrs, + NULL, fmstate->temp_cxt); /* tuple will be deleted when it is cleared from the slot */ ExecStoreTuple(newtup, slot, InvalidBuffer, true); } PG_CATCH(); { if (res) PQclear(res); PG_RE_THROW(); } @@ -2740,22 +2967,22 @@ analyze_row_processor(PGresult *res, int row, PgFdwAnalyzeState *astate) /* * Create sample tuple from current result row, and store it in the * position determined above. The tuple has to be created in anl_cxt. */ oldcontext = MemoryContextSwitchTo(astate->anl_cxt); astate->rows[pos] = make_tuple_from_result_row(res, row, astate->rel, astate->attinmeta, astate->retrieved_attrs, + NULL, astate->temp_cxt); - MemoryContextSwitchTo(oldcontext); } } /* * Import a foreign schema */ static List * postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid) { @@ -3015,65 +3242,338 @@ postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid) PG_RE_THROW(); } PG_END_TRY(); ReleaseConnection(conn); return commands; } /* + * Assess whether the join between inner and outer relations can be pushed down + * to the foreign server. As a side effect, save information we obtain in this + * function to PgFdwRelationInfo passed in. + * + * Joins that satisfy conditions below are safe to push down. + * + * 1) Join type is INNER or OUTER (one of LEFT/RIGHT/FULL) + * 2) Both outer and inner portions are safe to push-down + * 3) All foreign tables in the join belong to the same foreign server and use + * the same user mapping. + * 4) All join conditions are safe to push down + * 5) No relation has local filter (this can be relaxed for INNER JOIN, if we + * can move unpushable clauses upwards in the join tree). + */ +static bool +foreign_join_ok(PlannerInfo *root, RelOptInfo *joinrel, JoinType jointype, + RelOptInfo *outerrel, RelOptInfo *innerrel, + JoinPathExtraData *extra) +{ + PgFdwRelationInfo *fpinfo; + PgFdwRelationInfo *fpinfo_o; + PgFdwRelationInfo *fpinfo_i; + ListCell *lc; + List *joinclauses; + List *otherclauses; + + /* + * We support pushing down INNER, LEFT, RIGHT and FULL OUTER joins. + * Constructing queries representing SEMI and ANTI joins is hard, hence + * not considered right now. + */ + if (jointype != JOIN_INNER && jointype != JOIN_LEFT && + jointype != JOIN_RIGHT && jointype != JOIN_FULL) + return false; + + /* + * If either of the joining relations is marked as unsafe to pushdown, the + * join can not be pushed down. + */ + fpinfo = (PgFdwRelationInfo *) joinrel->fdw_private; + fpinfo_o = (PgFdwRelationInfo *) outerrel->fdw_private; + fpinfo_i = (PgFdwRelationInfo *) innerrel->fdw_private; + if (!fpinfo_o || !fpinfo_o->pushdown_safe || + !fpinfo_i || !fpinfo_i->pushdown_safe) + return false; + + /* + * If joining relations have local conditions, those conditions are required + * to be applied before joining the relations. Hence the join can not be + * pushed down. + */ + if (fpinfo_o->local_conds || fpinfo_i->local_conds) + return false; + + /* Separate restrict list into join quals and quals on join relation */ + if (IS_OUTER_JOIN(jointype)) + extract_actual_join_clauses(extra->restrictlist, &joinclauses, &otherclauses); + else + { + /* + * Unlike an outer join, for inner join, the join result contains only + * the rows which satisfy join clauses, similar to the other clause. + * Hence all clauses can be treated as other quals. This helps to push + * a join down to the foreign server even if some of its join quals are + * not safe to pushdown. + */ + otherclauses = extract_actual_clauses(extra->restrictlist, false); + joinclauses = NIL; + } + + /* Join quals must be safe to push down. */ + foreach(lc, joinclauses) + { + Expr *expr = (Expr *) lfirst(lc); + + if (!is_foreign_expr(root, joinrel, expr)) + return false; + } + + /* Save the join clauses, for later use. */ + fpinfo->joinclauses = joinclauses; + + /* + * Other clauses are applied after the join has been performed and thus need + * not be all pushable. We will push those which can be pushed to reduce the + * number of rows fetched from the foreign server. Rest of them will be + * applied locally after fetching join result. Add them to fpinfo so that + * other joins involving this joinrel will know that this joinrel has local + * clauses. + */ + foreach(lc, otherclauses) + { + Expr *expr = (Expr *) lfirst(lc); + + if (!is_foreign_expr(root, joinrel, expr)) + fpinfo->local_conds = lappend(fpinfo->local_conds, expr); + else + fpinfo->remote_conds = lappend(fpinfo->remote_conds, expr); + } + + fpinfo->outerrel = outerrel; + fpinfo->innerrel = innerrel; + fpinfo->jointype = jointype; + + /* + * If user is willing to estimate cost for a scan of either of the joining + * relations using EXPLAIN, he intends to estimate scans on that relation + * more accurately. Then, it makes sense to estimate the cost the join with + * that relation more accurately using EXPLAIN. + */ + fpinfo->use_remote_estimate = fpinfo_o->use_remote_estimate || + fpinfo_i->use_remote_estimate; + + /* + * Since both the joining relations come from the same server, the server + * level options should have same value for both the relations. Pick from any + * side. + */ + fpinfo->fdw_startup_cost = fpinfo_o->fdw_startup_cost; + fpinfo->fdw_tuple_cost = fpinfo_o->fdw_tuple_cost; + + return true; +} + +/* + * postgresGetForeignJoinPaths + * Add possible ForeignPath to joinrel, if join is safe to push down. + */ +static void +postgresGetForeignJoinPaths(PlannerInfo *root, + RelOptInfo *joinrel, + RelOptInfo *outerrel, + RelOptInfo *innerrel, + JoinType jointype, + JoinPathExtraData *extra) +{ + PgFdwRelationInfo *fpinfo; + ForeignPath *joinpath; + double rows; + int width; + Cost startup_cost; + Cost total_cost; + Path *epq_path; /* Path to create plan to be executed when + * EvalPlanQual gets triggered. + */ + + /* + * Skip if this join combination has been considered already. + */ + if (joinrel->fdw_private) + return; + + /* + * Create unfinished PgFdwRelationInfo entry which is used to indicate that + * the join relation is already considered, so that we won't waste time in + * judging safety of join pushdown and adding the same paths again if found + * safe. Once we know that this join can be pushed down, we fill the entry. + */ + fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo)); + fpinfo->pushdown_safe = false; + joinrel->fdw_private = fpinfo; + /* attrs_used is only for base relations. */ + fpinfo->attrs_used = NULL; + + if (!foreign_join_ok(root, joinrel, jointype, outerrel, innerrel, extra)) + return; + + /* + * In case there is a possibility that EvalPlanQual will be executed, we + * should be able to reconstruct the row, from base relations applying all + * the conditions. We create a local plan from a suitable local path + * available in the path list. In case such a path doesn't exist, we can not + * push the join to the foreign server since we won't be able to reconstruct + * the row for EvalPlanQual(). Find an alternative local path before we add + * ForeignPath, lest the new path would kick possibly the only local path. + */ + if (root->parse->commandType == CMD_DELETE || + root->parse->commandType == CMD_UPDATE || + root->rowMarks) + { + epq_path = GetPathForEPQRecheck(joinrel); + if (!epq_path) + { + elog(DEBUG3, "could not push down foreign join because a local path suitable for EPQ checks was not found"); + return; + } + } + else + epq_path = NULL; + + /* Mark that this join can be pushed down safely */ + fpinfo->pushdown_safe = true; + + /* + * Compute the selectivity and cost of the local_conds, so we don't have + * to do it over again for each path. The best we can do for these + * conditions is to estimate selectivity on the basis of local statistics. + * The local conditions are applied after the join has been computed on the + * remote side like quals in WHERE clause, so pass jointype as JOIN_INNER. + */ + fpinfo->local_conds_sel = clauselist_selectivity(root, + fpinfo->local_conds, + 0, + JOIN_INNER, + NULL); + cost_qual_eval(&fpinfo->local_conds_cost, fpinfo->local_conds, root); + + /* + * If we are going to estimate the costs using EXPLAIN, we will need + * connection information. Fill it here. + */ + if (fpinfo->use_remote_estimate) + fpinfo->user = GetUserMappingById(joinrel->umid); + else + { + fpinfo->user = NULL; + /* + * If we are going to estimate costs locally, estimate the join clause + * selectivity here while we have special join info. + */ + fpinfo->joinclause_sel = clauselist_selectivity(root, fpinfo->joinclauses, + 0, fpinfo->jointype, + extra->sjinfo); + + } + fpinfo->server = GetForeignServer(joinrel->serverid); + + /* Estimate costs for bare join relation */ + estimate_path_cost_size(root, joinrel, NIL, NIL, &rows, + &width, &startup_cost, &total_cost); + /* Now update this information in the joinrel */ + joinrel->rows = rows; + joinrel->width = width; + fpinfo->rows = rows; + fpinfo->width = width; + fpinfo->startup_cost = startup_cost; + fpinfo->total_cost = total_cost; + + /* + * Create a new join path and add it to the joinrel which represents a join + * between foreign tables. + */ + joinpath = create_foreignscan_path(root, + joinrel, + rows, + startup_cost, + total_cost, + NIL, /* no pathkeys */ + NULL, /* no required_outer */ + epq_path, + NULL); /* no fdw_private */ + + /* Add generated path into joinrel by add_path(). */ + add_path(joinrel, (Path *) joinpath); + + /* XXX Consider pathkeys for the join relation */ + + /* XXX Consider parameterized paths for the join relation */ +} + +/* * Create a tuple from the specified row of the PGresult. * * rel is the local representation of the foreign table, attinmeta is * conversion data for the rel's tupdesc, and retrieved_attrs is an * integer list of the table column numbers present in the PGresult. * temp_context is a working context that can be reset after each tuple. */ static HeapTuple make_tuple_from_result_row(PGresult *res, int row, Relation rel, AttInMetadata *attinmeta, List *retrieved_attrs, + ForeignScanState *fsstate, MemoryContext temp_context) { HeapTuple tuple; - TupleDesc tupdesc = RelationGetDescr(rel); + TupleDesc tupdesc; Datum *values; bool *nulls; ItemPointer ctid = NULL; ConversionLocation errpos; ErrorContextCallback errcallback; MemoryContext oldcontext; ListCell *lc; int j; Assert(row < PQntuples(res)); /* * Do the following work in a temp context that we reset after each tuple. * This cleans up not only the data we have direct access to, but any * cruft the I/O functions might leak. */ oldcontext = MemoryContextSwitchTo(temp_context); + if (rel) + tupdesc = RelationGetDescr(rel); + else + { + PgFdwScanState *fdw_sstate; + Assert(fsstate); + fdw_sstate = (PgFdwScanState *) fsstate->fdw_state; + tupdesc = fdw_sstate->tupdesc; + } + values = (Datum *) palloc0(tupdesc->natts * sizeof(Datum)); nulls = (bool *) palloc(tupdesc->natts * sizeof(bool)); /* Initialize to nulls for any columns not present in result */ memset(nulls, true, tupdesc->natts * sizeof(bool)); /* * Set up and install callback to report where conversion error occurs. */ errpos.rel = rel; errpos.cur_attno = 0; + errpos.fsstate = fsstate; errcallback.callback = conversion_error_callback; errcallback.arg = (void *) &errpos; errcallback.previous = error_context_stack; error_context_stack = &errcallback; /* * i indexes columns in the relation, j indexes columns in the PGresult. */ j = 0; foreach(lc, retrieved_attrs) @@ -3148,27 +3648,60 @@ make_tuple_from_result_row(PGresult *res, return tuple; } /* * Callback function which is called when error occurs during column value * conversion. Print names of column and relation. */ static void conversion_error_callback(void *arg) { + const char *attname; + const char *relname; ConversionLocation *errpos = (ConversionLocation *) arg; - TupleDesc tupdesc = RelationGetDescr(errpos->rel); - if (errpos->cur_attno > 0 && errpos->cur_attno <= tupdesc->natts) - errcontext("column \"%s\" of foreign table \"%s\"", - NameStr(tupdesc->attrs[errpos->cur_attno - 1]->attname), - RelationGetRelationName(errpos->rel)); + if (errpos->rel) + { + /* error occurred in a scan against a foreign table */ + TupleDesc tupdesc = RelationGetDescr(errpos->rel); + + if (errpos->cur_attno > 0 && errpos->cur_attno <= tupdesc->natts) + attname = NameStr(tupdesc->attrs[errpos->cur_attno - 1]->attname); + else if (errpos->cur_attno == SelfItemPointerAttributeNumber) + attname = "ctid"; + + relname = RelationGetRelationName(errpos->rel); + } + else + { + /* error occurred in a scan against a foreign join */ + ForeignScanState *fsstate = errpos->fsstate; + 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); + relname = get_rel_name(rte->relid); + attname = get_relid_attribute_name(rte->relid, var->varattno); + } + + if (attname && relname) + errcontext("column \"%s\" of foreign table \"%s\"", attname, relname); } /* * Find an equivalence class member expression, all of whose Vars, come from * the indicated relation. */ extern Expr * find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel) { ListCell *lc_em; diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h index bf83c91..2da19b8 100644 --- a/contrib/postgres_fdw/postgres_fdw.h +++ b/contrib/postgres_fdw/postgres_fdw.h @@ -19,47 +19,78 @@ #include "utils/relcache.h" #include "libpq-fe.h" /* * FDW-specific planner information kept in RelOptInfo.fdw_private for a * foreign table. This information is collected by postgresGetForeignRelSize. */ typedef struct PgFdwRelationInfo { - /* baserestrictinfo clauses, broken down into safe and unsafe subsets. */ + /* + * True means that the relation can be pushed down. Always true for + * simple foreign scan. + */ + bool pushdown_safe; + + /* + * Restriction clauses, divided into safe and unsafe to pushdown subsets. + * + * For a base foreign relation this is a list of clauses along-with + * RestrictInfo wrapper. Keeping RestrictInfo wrapper helps while dividing + * scna_clauses in postgresGetForeignPlan into safe and unsafe subsets. Also + * it helps in estimating costs since RestrictInfo caches the selectivity + * and qual cost for the clause in it. + * + * For a join relation, however, they are part of otherclause list obtained + * from extract_actual_join_clauses, which strips RestrictInfo construct. + * So, for a join relation they are list of bare clauses. + */ List *remote_conds; List *local_conds; /* Bitmap of attr numbers we need to fetch from the remote server. */ Bitmapset *attrs_used; /* Cost and selectivity of local_conds. */ QualCost local_conds_cost; Selectivity local_conds_sel; - /* Estimated size and cost for a scan with baserestrictinfo quals. */ + /* Selectivity of join conditions */ + Selectivity joinclause_sel; + + /* Estimated size and cost for a scan or join. */ double rows; int width; Cost startup_cost; Cost total_cost; + /* Costs excluding costs for transferring data from the foreign server */ + Cost rel_startup_cost; + Cost rel_total_cost; /* Options extracted from catalogs. */ bool use_remote_estimate; Cost fdw_startup_cost; Cost fdw_tuple_cost; List *shippable_extensions; /* OIDs of whitelisted extensions */ /* Cached catalog information. */ ForeignTable *table; ForeignServer *server; UserMapping *user; /* only set in use_remote_estimate mode */ + + + /* Join information */ + RelOptInfo *outerrel; + RelOptInfo *innerrel; + JoinType jointype; + List *joinclauses; } PgFdwRelationInfo; /* in postgres_fdw.c */ extern int set_transmission_modes(void); extern void reset_transmission_modes(int nestlevel); /* in connection.c */ extern PGconn *GetConnection(UserMapping *user, bool will_prep_stmt); extern void ReleaseConnection(PGconn *conn); extern unsigned int GetCursorNumber(PGconn *conn); @@ -93,19 +124,21 @@ extern void deparseUpdateSql(StringInfo buf, PlannerInfo *root, List **retrieved_attrs); extern void deparseDeleteSql(StringInfo buf, PlannerInfo *root, Index rtindex, Relation rel, List *returningList, List **retrieved_attrs); extern void deparseAnalyzeSizeSql(StringInfo buf, Relation rel); 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 void deparseSelectStmtForRel(StringInfo buf, PlannerInfo *root, - RelOptInfo *baserel, List *remote_conds, List *pathkeys, - List **retrieved_attrs, List **params_list); + RelOptInfo *baserel, List *remote_conds, List *pathkeys, + List **retrieved_attrs, List **params_list, List *tlist, + StringInfo relations); /* in shippable.c */ extern bool is_builtin(Oid objectId); extern bool is_shippable(Oid objectId, Oid classId, PgFdwRelationInfo *fpinfo); #endif /* POSTGRES_FDW_H */ diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index 5c6ead1..4ab0ba5 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -4,26 +4,31 @@ CREATE EXTENSION postgres_fdw; CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw; DO $d$ BEGIN EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw OPTIONS (dbname '$$||current_database()||$$', port '$$||current_setting('port')||$$' )$$; + EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw + OPTIONS (dbname '$$||current_database()||$$', + port '$$||current_setting('port')||$$' + )$$; END; $d$; CREATE USER MAPPING FOR public SERVER testserver1 OPTIONS (user 'value', password 'value'); CREATE USER MAPPING FOR CURRENT_USER SERVER loopback; +CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2; -- =================================================================== -- create objects used through FDW loopback server -- =================================================================== CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz'); CREATE SCHEMA "S 1"; CREATE TABLE "S 1"."T 1" ( "C 1" int NOT NULL, c2 int NOT NULL, c3 text, @@ -32,38 +37,64 @@ CREATE TABLE "S 1"."T 1" ( c6 varchar(10), c7 char(10), c8 user_enum, CONSTRAINT t1_pkey PRIMARY KEY ("C 1") ); CREATE TABLE "S 1"."T 2" ( c1 int NOT NULL, c2 text, CONSTRAINT t2_pkey PRIMARY KEY (c1) ); +CREATE TABLE "S 1"."T 3" ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text, + CONSTRAINT t3_pkey PRIMARY KEY (c1) +); +CREATE TABLE "S 1"."T 4" ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text, + CONSTRAINT t4_pkey PRIMARY KEY (c1) +); INSERT INTO "S 1"."T 1" SELECT id, id % 10, to_char(id, 'FM00000'), '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval, '1970-01-01'::timestamp + ((id % 100) || ' days')::interval, id % 10, id % 10, 'foo'::user_enum FROM generate_series(1, 1000) id; INSERT INTO "S 1"."T 2" SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id; +INSERT INTO "S 1"."T 3" + SELECT id, + id + 1, + 'AAA' || to_char(id, 'FM000') + FROM generate_series(1, 100) id; +DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests +INSERT INTO "S 1"."T 4" + SELECT id, + id + 1, + 'AAA' || to_char(id, 'FM000') + FROM generate_series(1, 100) id; +DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests ANALYZE "S 1"."T 1"; ANALYZE "S 1"."T 2"; +ANALYZE "S 1"."T 3"; +ANALYZE "S 1"."T 4"; -- =================================================================== -- create foreign tables -- =================================================================== CREATE FOREIGN TABLE ft1 ( c0 int, c1 int NOT NULL, c2 int NOT NULL, c3 text, c4 timestamptz, @@ -80,20 +111,38 @@ CREATE FOREIGN TABLE ft2 ( cx int, c3 text, c4 timestamptz, c5 timestamp, c6 varchar(10), c7 char(10) default 'ft2', c8 user_enum ) SERVER loopback; ALTER FOREIGN TABLE ft2 DROP COLUMN cx; +CREATE FOREIGN TABLE ft4 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3'); + +CREATE FOREIGN TABLE ft5 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4'); + +CREATE FOREIGN TABLE ft6 ( + c1 int NOT NULL, + c2 int NOT NULL, + c3 text +) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4'); + -- =================================================================== -- tests for validator -- =================================================================== -- requiressl, krbsrvname and gsslib are omitted because they depend on -- configure options ALTER SERVER testserver1 OPTIONS ( use_remote_estimate 'false', updatable 'true', fdw_startup_cost '123.456', fdw_tuple_cost '0.123', @@ -161,22 +210,20 @@ SELECT * FROM ft1 WHERE false; -- with WHERE clause EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1'; SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1'; -- with FOR UPDATE/SHARE EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE; SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE; EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE; SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE; -- aggregate SELECT COUNT(*) FROM ft1 t1; --- join two tables -SELECT t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; -- subquery SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1; -- subquery+MAX SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1; -- used in CTE WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1; -- fixed values SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1; -- Test forcing the remote server to produce sorted data for a merge join. SET enable_hashjoin TO false; @@ -201,24 +248,25 @@ EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l) EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE 1 = c1!; -- OpExpr(r) EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- ArrayRef EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote --- parameterized remote path +-- parameterized remote path for foreign table EXPLAIN (VERBOSE, COSTS false) - SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2; + SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2; SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2; + -- check both safe and unsafe join conditions EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft2 a, ft2 b WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7); SELECT * FROM ft2 a, ft2 b WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7); -- bug before 9.3.5 due to sloppy handling of remote-estimate parameters SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5)); SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5)); -- we should not push order by clause with volatile expressions or unsafe @@ -264,20 +312,172 @@ ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw'); -- ... now they can be shipped EXPLAIN (VERBOSE, COSTS false) SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2); SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2); EXPLAIN (VERBOSE, COSTS false) SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2; SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2; -- =================================================================== +-- JOIN queries +-- =================================================================== +-- Analyze ft4 and ft5 so that we have better statistics. These tables do not +-- have use_remote_estimate set. +ANALYZE ft4; +ANALYZE ft5; + +-- join two tables +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +-- join three tables +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10; +SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10; +-- left outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +-- left outer join + placement of clauses. +-- clauses within the nullable side are not pulled up, but top level clause on +-- non-nullable side is pushed into non-nullable side +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10; +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10; +-- clauses within the nullable side are not pulled up, but the top level clause +-- on nullable side is not pushed down into nullable side +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) + WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10; +SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) + WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10; +-- right outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10; +-- full outer join +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10; +-- full outer join + WHERE clause, only matched rows +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +-- join two tables with FOR UPDATE clause +-- tests whole-row reference for row marks +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1; +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE; +-- join two tables with FOR SHARE clause +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1; +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE; +-- join in CTE +EXPLAIN (COSTS false, VERBOSE) +WITH t (c1_1, c1_3, c2_1) AS (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10; +WITH t (c1_1, c1_3, c2_1) AS (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10; +-- ctid with whole-row reference +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +-- SEMI JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10; +-- ANTI JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10; +-- CROSS JOIN, not pushed down +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +-- different server, not pushed down. No result expected. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS +-- JOIN since c8 in both tables has same value. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +-- unsafe conditions on one side (c8 has a UDT), not pushed down. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +-- join where unsafe to pushdown condition in WHERE clause has a column not +-- in the SELECT clause. In this test unsafe clause needs to have column +-- references from both joining sides so that the clause is not pushed down +-- into one of the joining sides. +EXPLAIN (COSTS false, VERBOSE) +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10; +-- Aggregate after UNION, for testing setrefs +EXPLAIN (COSTS false, VERBOSE) +SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10; +SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10; +-- join with lateral reference +EXPLAIN (COSTS false, VERBOSE) +SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10; +SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10; + +-- create another user for permission, user mapping, effective user tests +CREATE USER view_owner; +-- grant privileges on ft4 and ft5 to view_owner +GRANT ALL ON ft4 TO view_owner; +GRANT ALL ON ft5 TO view_owner; +-- prepare statement with current session user +PREPARE join_stmt AS SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; +EXPLAIN (COSTS OFF, VERBOSE) EXECUTE join_stmt; +EXECUTE join_stmt; +-- change the session user to view_owner and execute the statement. Because of +-- change in session user, the plan should get invalidated and created again. +-- While creating the plan, it should throw error since there is no user mapping +-- available for view_owner. +SET SESSION ROLE view_owner; +EXPLAIN (COSTS OFF, VERBOSE) EXECUTE join_stmt; +EXECUTE join_stmt; +RESET ROLE; +DEALLOCATE join_stmt; + +CREATE VIEW v_ft5 AS SELECT * FROM ft5; +-- change owner of v_ft5 to view_owner so that the effective user for scan on +-- ft5 is view_owner and not the current user. +ALTER VIEW v_ft5 OWNER TO view_owner; +-- create a public user mapping for loopback server +-- drop user mapping for current_user. +DROP USER MAPPING FOR CURRENT_USER SERVER loopback; +CREATE USER MAPPING FOR PUBLIC SERVER loopback; +-- different effective user for permission check, but same user mapping for the +-- joining sides, join pushed down, no result expected. +PREPARE join_stmt AS SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN v_ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10; +EXPLAIN (COSTS false, VERBOSE) EXECUTE join_stmt; +EXECUTE join_stmt; +-- create user mapping for view_owner and execute the prepared statement +-- the join should not be pushed down since joining relations now use two +-- different user mappings +CREATE USER MAPPING FOR view_owner SERVER loopback; +EXPLAIN (COSTS false, VERBOSE) EXECUTE join_stmt; +EXECUTE join_stmt; + +-- recreate the dropped user mapping for further tests +CREATE USER MAPPING FOR CURRENT_USER SERVER loopback; +DROP USER MAPPING FOR PUBLIC SERVER loopback; + +-- =================================================================== -- parameterized queries -- =================================================================== -- simple join PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2; EXPLAIN (VERBOSE, COSTS false) EXECUTE st1(1, 2); EXECUTE st1(1, 1); EXECUTE st1(101, 101); -- subquery using stable function (can't be sent to remote) PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1; EXPLAIN (VERBOSE, COSTS false) EXECUTE st2(10, 20); @@ -341,20 +541,21 @@ BEGIN END; $$ LANGUAGE plpgsql; SELECT f_test(100); DROP FUNCTION f_test(int); -- =================================================================== -- 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 ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum; -- =================================================================== -- subtransaction -- + local/remote error doesn't break cursor -- =================================================================== BEGIN; DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1; FETCH c; SAVEPOINT s; @@ -913,10 +1114,14 @@ IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere; -- We can fake this by dropping the type locally in our transaction. CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue'); CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors"); CREATE SCHEMA import_dest5; BEGIN; DROP TYPE "Colors" CASCADE; IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5) FROM SERVER loopback INTO import_dest5; -- ERROR ROLLBACK; + +-- Cleanup +DROP OWNED BY view_owner; +DROP USER view_owner; diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml index dc2d890..77287fa 100644 --- a/doc/src/sgml/fdwhandler.sgml +++ b/doc/src/sgml/fdwhandler.sgml @@ -334,20 +334,34 @@ GetForeignJoinPaths (PlannerInfo *root, remote join cannot be found from the system catalogs, the FDW must fill fdw_scan_tlist with an appropriate list of TargetEntry nodes, representing the set of columns it will supply at run time in the tuples it returns. See for additional information. + + +void +GetPathForEPQRecheck(RelOptInfo *joinrel) + + The function returns copy of a local join path, which can be converted + into alternative local join plan, which in turn can be used by + RecheckForeignScan method. The function searches for a + suitable path in the pathlist of given joinrel. + If it does not find a suitable path, it returns NULL, in which case a + foreign data wrapper may build the local path by itself or may choose not + to create access paths for that join. + + FDW Routines For Updating Foreign Tables If an FDW supports writable foreign tables, it should provide some or all of the following callback functions depending on the needs and capabilities of the FDW: @@ -787,20 +801,23 @@ RecheckForeignScan (ForeignScanState *node, TupleTableSlot *slot); To implement join pushdown, a foreign data wrapper will typically construct an alternative local join plan which is used only for rechecks; this will become the outer subplan of the ForeignScan. When a recheck is required, this subplan can be executed and the resulting tuple can be stored in the slot. This plan need not be efficient since no base table will return more than one row; for example, it may implement all joins as nested loops. + GetPathForEPQRecheck may be used to search existing paths + for a suitable local join path, which can be converted into the alternative + local join plan. FDW Routines for <command>EXPLAIN</> void ExplainForeignScan (ForeignScanState *node, @@ -1015,20 +1032,34 @@ GetForeignTable(Oid relid); This function returns a ForeignTable object for the foreign table with the given OID. A ForeignTable object contains properties of the foreign table (see foreign/foreign.h for details). +UserMapping * +GetUserMappingById(Oid umid); + + + This function returns a UserMapping object for + the given user mapping OID. The OID of a user mapping is available in + RelOptInfo for a foreign scan. + (If there is no mapping for the OID, it will throw an error.) + A UserMapping object contains properties of the + user mapping (see foreign/foreign.h for details). + + + + List * GetForeignColumnOptions(Oid relid, AttrNumber attnum); This function returns the per-column FDW options for the column with the given foreign table OID and attribute number, in the form of a list of DefElem. NIL is returned if the column has no options. diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c index 47c00af..f728177 100644 --- a/src/backend/foreign/foreign.c +++ b/src/backend/foreign/foreign.c @@ -153,20 +153,68 @@ ForeignServer * GetForeignServerByName(const char *srvname, bool missing_ok) { Oid serverid = get_foreign_server_oid(srvname, missing_ok); if (!OidIsValid(serverid)) return NULL; return GetForeignServer(serverid); } +/* + * GetUserMappingById - look up the user mapping by its OID. + */ +UserMapping * +GetUserMappingById(Oid umid) +{ + Datum datum; + HeapTuple tp; + bool isnull; + UserMapping *um; + + tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(umid)); + if (!HeapTupleIsValid(tp)) + elog(ERROR, "cache lookup failed for user mapping %u", umid); + + um = (UserMapping *) palloc(sizeof(UserMapping)); + um->umid = umid; + + /* Extract the umuser */ + datum = SysCacheGetAttr(USERMAPPINGOID, + tp, + Anum_pg_user_mapping_umuser, + &isnull); + Assert(!isnull); + um->userid = DatumGetObjectId(datum); + + /* Extract the umserver */ + datum = SysCacheGetAttr(USERMAPPINGOID, + tp, + Anum_pg_user_mapping_umserver, + &isnull); + Assert(!isnull); + um->serverid = DatumGetObjectId(datum); + + /* Extract the umoptions */ + datum = SysCacheGetAttr(USERMAPPINGOID, + tp, + Anum_pg_user_mapping_umoptions, + &isnull); + if (isnull) + um->options = NIL; + else + um->options = untransformRelOptions(datum); + + ReleaseSysCache(tp); + + return um; +} /* * GetUserMapping - look up the user mapping. * * If no mapping is found for the supplied user, we also look for * PUBLIC mappings (userid == InvalidOid). */ UserMapping * GetUserMapping(Oid userid, Oid serverid) { @@ -725,10 +773,105 @@ get_foreign_server_oid(const char *servername, bool missing_ok) { Oid oid; oid = GetSysCacheOid1(FOREIGNSERVERNAME, CStringGetDatum(servername)); if (!OidIsValid(oid) && !missing_ok) ereport(ERROR, (errcode(ERRCODE_UNDEFINED_OBJECT), errmsg("server \"%s\" does not exist", servername))); return oid; } + +/* + * Get a copy of a local path for EPQ checks. + * + * Right now, we support only unparameterized foreign joins, so we only search + * for unparameterized path in the given list of paths. Since we are searching + * for an alternate local path for a foreign join, look for only MergeJoin, + * HashJoin or NestLoop paths. + * + * Since we will need to replace any foreign paths for join with their alternate + * paths, we need make a copy of the local path chosen. Make a shallow copy of + * the join path, because the planner might free the original structure after a + * future add_path(). We don't need to copy the substructure, though; that won't + * get freed. + * + * Since the plan created using this path will be used to execute the + * EPQ checks, efficiency of the path is not a concern. But since the list + * passed is expected to be from RelOptInfo, it's anyway sorted by total cost + * and hence we are likely to choose the most efficient path which suits our + * requirement. + */ +extern Path * +GetPathForEPQRecheck(RelOptInfo *joinrel) +{ + ListCell *lc; + + foreach(lc, joinrel->pathlist) + { + Path *path = (Path *) lfirst(lc); + JoinPath *joinpath; + + if (path->param_info == NULL) + { + switch (path->pathtype) + { + case T_HashJoin: + { + HashPath *hash_path = makeNode(HashPath); + memcpy(hash_path, path, sizeof(HashPath)); + joinpath = (JoinPath *)hash_path; + } + break; + + case T_NestLoop: + { + NestPath *nest_path = makeNode(NestPath); + memcpy(nest_path, path, sizeof(NestPath)); + joinpath = (JoinPath *)nest_path; + } + break; + + case T_MergeJoin: + { + MergePath *merge_path = makeNode(MergePath); + memcpy(merge_path, path, sizeof(MergePath)); + joinpath = (JoinPath *)merge_path; + } + break; + + default: + /* + * Just skip anything else. We don't know if corresponding + * plan would build the output row from whole-row references + * of base relations and execute the EPQ checks. + */ + break; + } + + /* + * If either inner or outer path is a ForeignPath corresponding to + * a pushed down join, replace it with the fdw_outerpath, so that we + * maintain path for EPQ checks built entirely of local join + * strategies. + */ + if (IsA(joinpath->outerjoinpath, ForeignPath)) + { + ForeignPath *foreign_path; + foreign_path = (ForeignPath *)joinpath->outerjoinpath; + if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL) + joinpath->outerjoinpath = foreign_path->fdw_outerpath; + } + + if (IsA(joinpath->innerjoinpath, ForeignPath)) + { + ForeignPath *foreign_path; + foreign_path = (ForeignPath *)joinpath->innerjoinpath; + if (foreign_path->path.parent->reloptkind == RELOPT_JOINREL) + joinpath->innerjoinpath = foreign_path->fdw_outerpath; + } + + return (Path *)joinpath; + } + } + return NULL; +} diff --git a/src/include/foreign/fdwapi.h b/src/include/foreign/fdwapi.h index db73233..fb190b6 100644 --- a/src/include/foreign/fdwapi.h +++ b/src/include/foreign/fdwapi.h @@ -181,12 +181,13 @@ typedef struct FdwRoutine /* Functions in foreign/foreign.c */ extern FdwRoutine *GetFdwRoutine(Oid fdwhandler); extern Oid GetForeignServerIdByRelId(Oid relid); extern FdwRoutine *GetFdwRoutineByServerId(Oid serverid); extern FdwRoutine *GetFdwRoutineByRelId(Oid relid); extern FdwRoutine *GetFdwRoutineForRelation(Relation relation, bool makecopy); extern bool IsImportableForeignTable(const char *tablename, ImportForeignSchemaStmt *stmt); +extern Path *GetPathForEPQRecheck(RelOptInfo *joinrel); #endif /* FDWAPI_H */ diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h index d135916..71f8e55 100644 --- a/src/include/foreign/foreign.h +++ b/src/include/foreign/foreign.h @@ -66,20 +66,21 @@ typedef struct ForeignTable Oid relid; /* relation Oid */ Oid serverid; /* server Oid */ List *options; /* ftoptions as DefElem list */ } ForeignTable; extern ForeignServer *GetForeignServer(Oid serverid); extern ForeignServer *GetForeignServerByName(const char *name, bool missing_ok); extern UserMapping *GetUserMapping(Oid userid, Oid serverid); extern Oid GetUserMappingId(Oid userid, Oid serverid); +extern UserMapping *GetUserMappingById(Oid umid); extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid); extern ForeignDataWrapper *GetForeignDataWrapperByName(const char *name, bool missing_ok); extern ForeignTable *GetForeignTable(Oid relid); extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum); extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok); extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);