diff --git a/contrib/Makefile b/contrib/Makefile
index fcd7c1e0330212d317f8793922ac3263ba14fac8..ae2b7d0f1f103753357e8df54f6337dad69ad8f1 100644
--- a/contrib/Makefile
+++ b/contrib/Makefile
@@ -43,6 +43,7 @@ SUBDIRS = \
 		pgcrypto	\
 		pgrowlocks	\
 		pgstattuple	\
+		postgres_fdw	\
 		seg		\
 		spi		\
 		tablefunc	\
diff --git a/contrib/postgres_fdw/.gitignore b/contrib/postgres_fdw/.gitignore
new file mode 100644
index 0000000000000000000000000000000000000000..5dcb3ff9723501c3fe639bee1c1435e47a580a6f
--- /dev/null
+++ b/contrib/postgres_fdw/.gitignore
@@ -0,0 +1,4 @@
+# Generated subdirectories
+/log/
+/results/
+/tmp_check/
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
new file mode 100644
index 0000000000000000000000000000000000000000..8c497201d0e7705e39fc0028cf62d8a771dc659c
--- /dev/null
+++ b/contrib/postgres_fdw/Makefile
@@ -0,0 +1,27 @@
+# contrib/postgres_fdw/Makefile
+
+MODULE_big = postgres_fdw
+OBJS = postgres_fdw.o option.o deparse.o connection.o
+
+PG_CPPFLAGS = -I$(libpq_srcdir)
+SHLIB_LINK = $(libpq)
+SHLIB_PREREQS = submake-libpq
+
+EXTENSION = postgres_fdw
+DATA = postgres_fdw--1.0.sql
+
+REGRESS = postgres_fdw
+
+# the db name is hard-coded in the tests
+override USE_MODULE_DB =
+
+ifdef USE_PGXS
+PG_CONFIG = pg_config
+PGXS := $(shell $(PG_CONFIG) --pgxs)
+include $(PGXS)
+else
+subdir = contrib/postgres_fdw
+top_builddir = ../..
+include $(top_builddir)/src/Makefile.global
+include $(top_srcdir)/contrib/contrib-global.mk
+endif
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
new file mode 100644
index 0000000000000000000000000000000000000000..62ccea4c460bfd5218ac612657e007e125b1d09e
--- /dev/null
+++ b/contrib/postgres_fdw/connection.c
@@ -0,0 +1,581 @@
+/*-------------------------------------------------------------------------
+ *
+ * connection.c
+ *		  Connection management functions for postgres_fdw
+ *
+ * Portions Copyright (c) 2012-2013, PostgreSQL Global Development Group
+ *
+ * IDENTIFICATION
+ *		  contrib/postgres_fdw/connection.c
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "postgres_fdw.h"
+
+#include "access/xact.h"
+#include "mb/pg_wchar.h"
+#include "miscadmin.h"
+#include "utils/hsearch.h"
+#include "utils/memutils.h"
+
+
+/*
+ * Connection cache hash table entry
+ *
+ * The lookup key in this hash table is the foreign server OID plus the user
+ * mapping OID.  (We use just one connection per user per foreign server,
+ * so that we can ensure all scans use the same snapshot during a query.)
+ *
+ * The "conn" pointer can be NULL if we don't currently have a live connection.
+ * When we do have a connection, xact_depth tracks the current depth of
+ * transactions and subtransactions open on the remote side.  We need to issue
+ * commands at the same nesting depth on the remote as we're executing at
+ * ourselves, so that rolling back a subtransaction will kill the right
+ * queries and not the wrong ones.
+ */
+typedef struct ConnCacheKey
+{
+	Oid			serverid;		/* OID of foreign server */
+	Oid			userid;			/* OID of local user whose mapping we use */
+} ConnCacheKey;
+
+typedef struct ConnCacheEntry
+{
+	ConnCacheKey key;			/* hash key (must be first) */
+	PGconn	   *conn;			/* connection to foreign server, or NULL */
+	int			xact_depth;		/* 0 = no xact open, 1 = main xact open, 2 =
+								 * one level of subxact open, etc */
+} ConnCacheEntry;
+
+/*
+ * Connection cache (initialized on first use)
+ */
+static HTAB *ConnectionHash = NULL;
+
+/* for assigning cursor numbers */
+static unsigned int cursor_number = 0;
+
+/* tracks whether any work is needed in callback functions */
+static bool xact_got_connection = false;
+
+/* prototypes of private functions */
+static PGconn *connect_pg_server(ForeignServer *server, UserMapping *user);
+static void check_conn_params(const char **keywords, const char **values);
+static void begin_remote_xact(ConnCacheEntry *entry);
+static void pgfdw_xact_callback(XactEvent event, void *arg);
+static void pgfdw_subxact_callback(SubXactEvent event,
+					   SubTransactionId mySubid,
+					   SubTransactionId parentSubid,
+					   void *arg);
+
+
+/*
+ * Get a PGconn which can be used to execute queries on the remote PostgreSQL
+ * server with the user's authorization.  A new connection is established
+ * if we don't already have a suitable one, and a transaction is opened at
+ * the right subtransaction nesting depth if we didn't do that already.
+ *
+ * XXX Note that caching connections theoretically requires a mechanism to
+ * detect change of FDW objects to invalidate already established connections.
+ * We could manage that by watching for invalidation events on the relevant
+ * syscaches.  For the moment, though, it's not clear that this would really
+ * be useful and not mere pedantry.  We could not flush any active connections
+ * mid-transaction anyway.
+ */
+PGconn *
+GetConnection(ForeignServer *server, UserMapping *user)
+{
+	bool		found;
+	ConnCacheEntry *entry;
+	ConnCacheKey key;
+
+	/* First time through, initialize connection cache hashtable */
+	if (ConnectionHash == NULL)
+	{
+		HASHCTL		ctl;
+
+		MemSet(&ctl, 0, sizeof(ctl));
+		ctl.keysize = sizeof(ConnCacheKey);
+		ctl.entrysize = sizeof(ConnCacheEntry);
+		ctl.hash = tag_hash;
+		/* allocate ConnectionHash in the cache context */
+		ctl.hcxt = CacheMemoryContext;
+		ConnectionHash = hash_create("postgres_fdw connections", 8,
+									 &ctl,
+								   HASH_ELEM | HASH_FUNCTION | HASH_CONTEXT);
+
+		/*
+		 * Register some callback functions that manage connection cleanup.
+		 * This should be done just once in each backend.
+		 */
+		RegisterXactCallback(pgfdw_xact_callback, NULL);
+		RegisterSubXactCallback(pgfdw_subxact_callback, NULL);
+	}
+
+	/* Set flag that we did GetConnection during the current transaction */
+	xact_got_connection = true;
+
+	/* Create hash key for the entry.  Assume no pad bytes in key struct */
+	key.serverid = server->serverid;
+	key.userid = user->userid;
+
+	/*
+	 * Find or create cached entry for requested connection.
+	 */
+	entry = hash_search(ConnectionHash, &key, HASH_ENTER, &found);
+	if (!found)
+	{
+		/* initialize new hashtable entry (key is already filled in) */
+		entry->conn = NULL;
+		entry->xact_depth = 0;
+	}
+
+	/*
+	 * We don't check the health of cached connection here, because it would
+	 * require some overhead.  Broken connection will be detected when the
+	 * connection is actually used.
+	 */
+
+	/*
+	 * If cache entry doesn't have a connection, we have to establish a new
+	 * connection.	(If connect_pg_server throws an error, the cache entry
+	 * will be left in a valid empty state.)
+	 */
+	if (entry->conn == NULL)
+	{
+		entry->xact_depth = 0;	/* just to be sure */
+		entry->conn = connect_pg_server(server, user);
+		elog(DEBUG3, "new postgres_fdw connection %p for server \"%s\"",
+			 entry->conn, server->servername);
+	}
+
+	/*
+	 * Start a new transaction or subtransaction if needed.
+	 */
+	begin_remote_xact(entry);
+
+	return entry->conn;
+}
+
+/*
+ * Connect to remote server using specified server and user mapping properties.
+ */
+static PGconn *
+connect_pg_server(ForeignServer *server, UserMapping *user)
+{
+	PGconn	   *volatile conn = NULL;
+
+	/*
+	 * Use PG_TRY block to ensure closing connection on error.
+	 */
+	PG_TRY();
+	{
+		const char **keywords;
+		const char **values;
+		int			n;
+
+		/*
+		 * Construct connection params from generic options of ForeignServer
+		 * and UserMapping.  (Some of them might not be libpq options, in
+		 * which case we'll just waste a few array slots.)  Add 3 extra slots
+		 * for fallback_application_name, client_encoding, end marker.
+		 */
+		n = list_length(server->options) + list_length(user->options) + 3;
+		keywords = (const char **) palloc(n * sizeof(char *));
+		values = (const char **) palloc(n * sizeof(char *));
+
+		n = 0;
+		n += ExtractConnectionOptions(server->options,
+									  keywords + n, values + n);
+		n += ExtractConnectionOptions(user->options,
+									  keywords + n, values + n);
+
+		/* Use "postgres_fdw" as fallback_application_name. */
+		keywords[n] = "fallback_application_name";
+		values[n] = "postgres_fdw";
+		n++;
+
+		/* Set client_encoding so that libpq can convert encoding properly. */
+		keywords[n] = "client_encoding";
+		values[n] = GetDatabaseEncodingName();
+		n++;
+
+		keywords[n] = values[n] = NULL;
+
+		/* verify connection parameters and make connection */
+		check_conn_params(keywords, values);
+
+		conn = PQconnectdbParams(keywords, values, false);
+		if (!conn || PQstatus(conn) != CONNECTION_OK)
+		{
+			char	   *connmessage;
+			int			msglen;
+
+			/* libpq typically appends a newline, strip that */
+			connmessage = pstrdup(PQerrorMessage(conn));
+			msglen = strlen(connmessage);
+			if (msglen > 0 && connmessage[msglen - 1] == '\n')
+				connmessage[msglen - 1] = '\0';
+			ereport(ERROR,
+			   (errcode(ERRCODE_SQLCLIENT_UNABLE_TO_ESTABLISH_SQLCONNECTION),
+				errmsg("could not connect to server \"%s\"",
+					   server->servername),
+				errdetail_internal("%s", connmessage)));
+		}
+
+		/*
+		 * Check that non-superuser has used password to establish connection;
+		 * otherwise, he's piggybacking on the postgres server's user
+		 * identity. See also dblink_security_check() in contrib/dblink.
+		 */
+		if (!superuser() && !PQconnectionUsedPassword(conn))
+			ereport(ERROR,
+				  (errcode(ERRCODE_S_R_E_PROHIBITED_SQL_STATEMENT_ATTEMPTED),
+				   errmsg("password is required"),
+				   errdetail("Non-superuser cannot connect if the server does not request a password."),
+				   errhint("Target server's authentication method must be changed.")));
+
+		pfree(keywords);
+		pfree(values);
+	}
+	PG_CATCH();
+	{
+		/* Release PGconn data structure if we managed to create one */
+		if (conn)
+			PQfinish(conn);
+		PG_RE_THROW();
+	}
+	PG_END_TRY();
+
+	return conn;
+}
+
+/*
+ * For non-superusers, insist that the connstr specify a password.	This
+ * prevents a password from being picked up from .pgpass, a service file,
+ * the environment, etc.  We don't want the postgres user's passwords
+ * to be accessible to non-superusers.	(See also dblink_connstr_check in
+ * contrib/dblink.)
+ */
+static void
+check_conn_params(const char **keywords, const char **values)
+{
+	int			i;
+
+	/* no check required if superuser */
+	if (superuser())
+		return;
+
+	/* ok if params contain a non-empty password */
+	for (i = 0; keywords[i] != NULL; i++)
+	{
+		if (strcmp(keywords[i], "password") == 0 && values[i][0] != '\0')
+			return;
+	}
+
+	ereport(ERROR,
+			(errcode(ERRCODE_S_R_E_PROHIBITED_SQL_STATEMENT_ATTEMPTED),
+			 errmsg("password is required"),
+			 errdetail("Non-superusers must provide a password in the user mapping.")));
+}
+
+/*
+ * Start remote transaction or subtransaction, if needed.
+ *
+ * Note that we always use at least REPEATABLE READ in the remote session.
+ * This is so that, if a query initiates multiple scans of the same or
+ * different foreign tables, we will get snapshot-consistent results from
+ * those scans.  A disadvantage is that we can't provide sane emulation of
+ * READ COMMITTED behavior --- it would be nice if we had some other way to
+ * control which remote queries share a snapshot.
+ */
+static void
+begin_remote_xact(ConnCacheEntry *entry)
+{
+	int			curlevel = GetCurrentTransactionNestLevel();
+	PGresult   *res;
+
+	/* Start main transaction if we haven't yet */
+	if (entry->xact_depth <= 0)
+	{
+		const char *sql;
+
+		elog(DEBUG3, "starting remote transaction on connection %p",
+			 entry->conn);
+
+		if (XactIsoLevel == XACT_SERIALIZABLE)
+			sql = "START TRANSACTION ISOLATION LEVEL SERIALIZABLE";
+		else
+			sql = "START TRANSACTION ISOLATION LEVEL REPEATABLE READ";
+		res = PQexec(entry->conn, sql);
+		if (PQresultStatus(res) != PGRES_COMMAND_OK)
+			pgfdw_report_error(ERROR, res, true, sql);
+		PQclear(res);
+		entry->xact_depth = 1;
+	}
+
+	/*
+	 * If we're in a subtransaction, stack up savepoints to match our level.
+	 * This ensures we can rollback just the desired effects when a
+	 * subtransaction aborts.
+	 */
+	while (entry->xact_depth < curlevel)
+	{
+		char		sql[64];
+
+		snprintf(sql, sizeof(sql), "SAVEPOINT s%d", entry->xact_depth + 1);
+		res = PQexec(entry->conn, sql);
+		if (PQresultStatus(res) != PGRES_COMMAND_OK)
+			pgfdw_report_error(ERROR, res, true, sql);
+		PQclear(res);
+		entry->xact_depth++;
+	}
+}
+
+/*
+ * Release connection reference count created by calling GetConnection.
+ */
+void
+ReleaseConnection(PGconn *conn)
+{
+	/*
+	 * Currently, we don't actually track connection references because all
+	 * cleanup is managed on a transaction or subtransaction basis instead. So
+	 * there's nothing to do here.
+	 */
+}
+
+/*
+ * Assign a "unique" number for a cursor.
+ *
+ * These really only need to be unique per connection within a transaction.
+ * For the moment we ignore the per-connection point and assign them across
+ * all connections in the transaction, but we ask for the connection to be
+ * supplied in case we want to refine that.
+ *
+ * Note that even if wraparound happens in a very long transaction, actual
+ * collisions are highly improbable; just be sure to use %u not %d to print.
+ */
+unsigned int
+GetCursorNumber(PGconn *conn)
+{
+	return ++cursor_number;
+}
+
+/*
+ * Report an error we got from the remote server.
+ *
+ * elevel: error level to use (typically ERROR, but might be less)
+ * res: PGresult containing the error
+ * clear: if true, PQclear the result (otherwise caller will handle it)
+ * sql: NULL, or text of remote command we tried to execute
+ */
+void
+pgfdw_report_error(int elevel, PGresult *res, bool clear, const char *sql)
+{
+	/* If requested, PGresult must be released before leaving this function. */
+	PG_TRY();
+	{
+		char	   *diag_sqlstate = PQresultErrorField(res, PG_DIAG_SQLSTATE);
+		char	   *message_primary = PQresultErrorField(res, PG_DIAG_MESSAGE_PRIMARY);
+		char	   *message_detail = PQresultErrorField(res, PG_DIAG_MESSAGE_DETAIL);
+		char	   *message_hint = PQresultErrorField(res, PG_DIAG_MESSAGE_HINT);
+		char	   *message_context = PQresultErrorField(res, PG_DIAG_CONTEXT);
+		int			sqlstate;
+
+		if (diag_sqlstate)
+			sqlstate = MAKE_SQLSTATE(diag_sqlstate[0],
+									 diag_sqlstate[1],
+									 diag_sqlstate[2],
+									 diag_sqlstate[3],
+									 diag_sqlstate[4]);
+		else
+			sqlstate = ERRCODE_CONNECTION_FAILURE;
+
+		ereport(elevel,
+				(errcode(sqlstate),
+				 message_primary ? errmsg_internal("%s", message_primary) :
+				 errmsg("unknown error"),
+			   message_detail ? errdetail_internal("%s", message_detail) : 0,
+				 message_hint ? errhint("%s", message_hint) : 0,
+				 message_context ? errcontext("%s", message_context) : 0,
+				 sql ? errcontext("Remote SQL command: %s", sql) : 0));
+	}
+	PG_CATCH();
+	{
+		if (clear)
+			PQclear(res);
+		PG_RE_THROW();
+	}
+	PG_END_TRY();
+	if (clear)
+		PQclear(res);
+}
+
+/*
+ * pgfdw_xact_callback --- cleanup at main-transaction end.
+ */
+static void
+pgfdw_xact_callback(XactEvent event, void *arg)
+{
+	HASH_SEQ_STATUS scan;
+	ConnCacheEntry *entry;
+
+	/* Quick exit if no connections were touched in this transaction. */
+	if (!xact_got_connection)
+		return;
+
+	/*
+	 * Scan all connection cache entries to find open remote transactions, and
+	 * close them.
+	 */
+	hash_seq_init(&scan, ConnectionHash);
+	while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+	{
+		PGresult   *res;
+
+		/* We only care about connections with open remote transactions */
+		if (entry->conn == NULL || entry->xact_depth == 0)
+			continue;
+
+		elog(DEBUG3, "closing remote transaction on connection %p",
+			 entry->conn);
+
+		switch (event)
+		{
+			case XACT_EVENT_PRE_COMMIT:
+				/* Commit all remote transactions during pre-commit */
+				res = PQexec(entry->conn, "COMMIT TRANSACTION");
+				if (PQresultStatus(res) != PGRES_COMMAND_OK)
+					pgfdw_report_error(ERROR, res, true, "COMMIT TRANSACTION");
+				PQclear(res);
+				break;
+			case XACT_EVENT_PRE_PREPARE:
+
+				/*
+				 * We disallow remote transactions that modified anything,
+				 * since it's not really reasonable to hold them open until
+				 * the prepared transaction is committed.  For the moment,
+				 * throw error unconditionally; later we might allow read-only
+				 * cases.  Note that the error will cause us to come right
+				 * back here with event == XACT_EVENT_ABORT, so we'll clean up
+				 * the connection state at that point.
+				 */
+				ereport(ERROR,
+						(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+						 errmsg("cannot prepare a transaction that modified remote tables")));
+				break;
+			case XACT_EVENT_COMMIT:
+			case XACT_EVENT_PREPARE:
+				/* Should not get here -- pre-commit should have handled it */
+				elog(ERROR, "missed cleaning up connection during pre-commit");
+				break;
+			case XACT_EVENT_ABORT:
+				/* If we're aborting, abort all remote transactions too */
+				res = PQexec(entry->conn, "ABORT TRANSACTION");
+				/* Note: can't throw ERROR, it would be infinite loop */
+				if (PQresultStatus(res) != PGRES_COMMAND_OK)
+					pgfdw_report_error(WARNING, res, true,
+									   "ABORT TRANSACTION");
+				else
+					PQclear(res);
+				break;
+		}
+
+		/* Reset state to show we're out of a transaction */
+		entry->xact_depth = 0;
+
+		/*
+		 * If the connection isn't in a good idle state, discard it to
+		 * recover. Next GetConnection will open a new connection.
+		 */
+		if (PQstatus(entry->conn) != CONNECTION_OK ||
+			PQtransactionStatus(entry->conn) != PQTRANS_IDLE)
+		{
+			elog(DEBUG3, "discarding connection %p", entry->conn);
+			PQfinish(entry->conn);
+			entry->conn = NULL;
+		}
+	}
+
+	/*
+	 * Regardless of the event type, we can now mark ourselves as out of the
+	 * transaction.  (Note: if we are here during PRE_COMMIT or PRE_PREPARE,
+	 * this saves a useless scan of the hashtable during COMMIT or PREPARE.)
+	 */
+	xact_got_connection = false;
+
+	/* Also reset cursor numbering for next transaction */
+	cursor_number = 0;
+}
+
+/*
+ * pgfdw_subxact_callback --- cleanup at subtransaction end.
+ */
+static void
+pgfdw_subxact_callback(SubXactEvent event, SubTransactionId mySubid,
+					   SubTransactionId parentSubid, void *arg)
+{
+	HASH_SEQ_STATUS scan;
+	ConnCacheEntry *entry;
+	int			curlevel;
+
+	/* Nothing to do at subxact start, nor after commit. */
+	if (!(event == SUBXACT_EVENT_PRE_COMMIT_SUB ||
+		  event == SUBXACT_EVENT_ABORT_SUB))
+		return;
+
+	/* Quick exit if no connections were touched in this transaction. */
+	if (!xact_got_connection)
+		return;
+
+	/*
+	 * Scan all connection cache entries to find open remote subtransactions
+	 * of the current level, and close them.
+	 */
+	curlevel = GetCurrentTransactionNestLevel();
+	hash_seq_init(&scan, ConnectionHash);
+	while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+	{
+		PGresult   *res;
+		char		sql[100];
+
+		/*
+		 * We only care about connections with open remote subtransactions of
+		 * the current level.
+		 */
+		if (entry->conn == NULL || entry->xact_depth < curlevel)
+			continue;
+
+		if (entry->xact_depth > curlevel)
+			elog(ERROR, "missed cleaning up remote subtransaction at level %d",
+				 entry->xact_depth);
+
+		if (event == SUBXACT_EVENT_PRE_COMMIT_SUB)
+		{
+			/* Commit all remote subtransactions during pre-commit */
+			snprintf(sql, sizeof(sql), "RELEASE SAVEPOINT s%d", curlevel);
+			res = PQexec(entry->conn, sql);
+			if (PQresultStatus(res) != PGRES_COMMAND_OK)
+				pgfdw_report_error(ERROR, res, true, sql);
+			PQclear(res);
+		}
+		else
+		{
+			/* Rollback all remote subtransactions during abort */
+			snprintf(sql, sizeof(sql),
+					 "ROLLBACK TO SAVEPOINT s%d; RELEASE SAVEPOINT s%d",
+					 curlevel, curlevel);
+			res = PQexec(entry->conn, sql);
+			if (PQresultStatus(res) != PGRES_COMMAND_OK)
+				pgfdw_report_error(WARNING, res, true, sql);
+			else
+				PQclear(res);
+		}
+
+		/* OK, we're outta that level of subtransaction */
+		entry->xact_depth--;
+	}
+}
diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
new file mode 100644
index 0000000000000000000000000000000000000000..7fc1f797ab2ec8ef7e86f3232ecb7232f573cef5
--- /dev/null
+++ b/contrib/postgres_fdw/deparse.c
@@ -0,0 +1,1104 @@
+/*-------------------------------------------------------------------------
+ *
+ * deparse.c
+ *		  Query deparser for postgres_fdw
+ *
+ * This file includes functions that examine query WHERE clauses to see
+ * whether they're safe to send to the remote server for execution, as
+ * well as functions to construct the query text to be sent.  The latter
+ * functionality is annoyingly duplicative of ruleutils.c, but there are
+ * enough special considerations that it seems best to keep this separate.
+ * One saving grace is that we only need deparse logic for node types that
+ * we consider safe to send.
+ *
+ * Portions Copyright (c) 2012-2013, PostgreSQL Global Development Group
+ *
+ * IDENTIFICATION
+ *		  contrib/postgres_fdw/deparse.c
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "postgres_fdw.h"
+
+#include "access/htup_details.h"
+#include "access/sysattr.h"
+#include "access/transam.h"
+#include "catalog/pg_operator.h"
+#include "catalog/pg_proc.h"
+#include "catalog/pg_type.h"
+#include "commands/defrem.h"
+#include "nodes/nodeFuncs.h"
+#include "optimizer/clauses.h"
+#include "optimizer/var.h"
+#include "parser/parsetree.h"
+#include "utils/builtins.h"
+#include "utils/lsyscache.h"
+#include "utils/syscache.h"
+
+
+/*
+ * Context for foreign_expr_walker's search of an expression tree.
+ */
+typedef struct foreign_expr_cxt
+{
+	/* Input values */
+	PlannerInfo *root;
+	RelOptInfo *foreignrel;
+	/* Result values */
+	List	   *param_numbers;	/* Param IDs of PARAM_EXTERN Params */
+} foreign_expr_cxt;
+
+/*
+ * Functions to determine whether an expression can be evaluated safely on
+ * remote server.
+ */
+static bool is_foreign_expr(PlannerInfo *root, RelOptInfo *baserel,
+				Expr *expr, List **param_numbers);
+static bool foreign_expr_walker(Node *node, foreign_expr_cxt *context);
+static bool is_builtin(Oid procid);
+
+/*
+ * Functions to construct string representation of a node tree.
+ */
+static void deparseColumnRef(StringInfo buf, int varno, int varattno,
+				 PlannerInfo *root);
+static void deparseRelation(StringInfo buf, Oid relid);
+static void deparseStringLiteral(StringInfo buf, const char *val);
+static void deparseExpr(StringInfo buf, Expr *expr, PlannerInfo *root);
+static void deparseVar(StringInfo buf, Var *node, PlannerInfo *root);
+static void deparseConst(StringInfo buf, Const *node, PlannerInfo *root);
+static void deparseParam(StringInfo buf, Param *node, PlannerInfo *root);
+static void deparseArrayRef(StringInfo buf, ArrayRef *node, PlannerInfo *root);
+static void deparseFuncExpr(StringInfo buf, FuncExpr *node, PlannerInfo *root);
+static void deparseOpExpr(StringInfo buf, OpExpr *node, PlannerInfo *root);
+static void deparseDistinctExpr(StringInfo buf, DistinctExpr *node,
+					PlannerInfo *root);
+static void deparseScalarArrayOpExpr(StringInfo buf, ScalarArrayOpExpr *node,
+						 PlannerInfo *root);
+static void deparseRelabelType(StringInfo buf, RelabelType *node,
+				   PlannerInfo *root);
+static void deparseBoolExpr(StringInfo buf, BoolExpr *node, PlannerInfo *root);
+static void deparseNullTest(StringInfo buf, NullTest *node, PlannerInfo *root);
+static void deparseArrayExpr(StringInfo buf, ArrayExpr *node,
+				 PlannerInfo *root);
+
+
+/*
+ * Examine each restriction clause in baserel's baserestrictinfo list,
+ * and classify them into three groups, which are returned as three lists:
+ *	- remote_conds contains expressions that can be evaluated remotely,
+ *	  and contain no PARAM_EXTERN Params
+ *	- param_conds contains expressions that can be evaluated remotely,
+ *	  but contain one or more PARAM_EXTERN Params
+ *	- local_conds contains all expressions that can't be evaluated remotely
+ *
+ * In addition, the fourth output parameter param_numbers receives an integer
+ * list of the param IDs of the PARAM_EXTERN Params used in param_conds.
+ *
+ * The reason for segregating param_conds is mainly that it's difficult to
+ * use such conditions in remote EXPLAIN.  We could do it, but unless the
+ * planner has been given representative values for all the Params, we'd
+ * have to guess at representative values to use in EXPLAIN EXECUTE.
+ * So for now we don't include them when doing remote EXPLAIN.
+ */
+void
+classifyConditions(PlannerInfo *root,
+				   RelOptInfo *baserel,
+				   List **remote_conds,
+				   List **param_conds,
+				   List **local_conds,
+				   List **param_numbers)
+{
+	ListCell   *lc;
+
+	*remote_conds = NIL;
+	*param_conds = NIL;
+	*local_conds = NIL;
+	*param_numbers = NIL;
+
+	foreach(lc, baserel->baserestrictinfo)
+	{
+		RestrictInfo *ri = (RestrictInfo *) lfirst(lc);
+		List	   *cur_param_numbers;
+
+		if (is_foreign_expr(root, baserel, ri->clause, &cur_param_numbers))
+		{
+			if (cur_param_numbers == NIL)
+				*remote_conds = lappend(*remote_conds, ri);
+			else
+			{
+				*param_conds = lappend(*param_conds, ri);
+				/* Use list_concat_unique_int to get rid of duplicates */
+				*param_numbers = list_concat_unique_int(*param_numbers,
+														cur_param_numbers);
+			}
+		}
+		else
+			*local_conds = lappend(*local_conds, ri);
+	}
+}
+
+/*
+ * Returns true if given expr is safe to evaluate on the foreign server.
+ *
+ * If result is true, we also return a list of param IDs of PARAM_EXTERN
+ * Params appearing in the expr into *param_numbers.
+ */
+static bool
+is_foreign_expr(PlannerInfo *root,
+				RelOptInfo *baserel,
+				Expr *expr,
+				List **param_numbers)
+{
+	foreign_expr_cxt context;
+
+	*param_numbers = NIL;		/* default result */
+
+	/*
+	 * Check that the expression consists of nodes that are safe to execute
+	 * remotely.
+	 */
+	context.root = root;
+	context.foreignrel = baserel;
+	context.param_numbers = NIL;
+	if (foreign_expr_walker((Node *) expr, &context))
+		return false;
+
+	/*
+	 * An expression which includes any mutable functions can't be sent over
+	 * because its result is not stable.  For example, sending now() remote
+	 * side could cause confusion from clock offsets.  Future versions might
+	 * be able to make this choice with more granularity.  (We check this last
+	 * because it requires a lot of expensive catalog lookups.)
+	 */
+	if (contain_mutable_functions((Node *) expr))
+		return false;
+
+	/*
+	 * OK, so return list of param IDs too.
+	 */
+	*param_numbers = context.param_numbers;
+
+	return true;
+}
+
+/*
+ * Return true if expression includes any node that is not safe to execute
+ * remotely.  (We use this convention because expression_tree_walker is
+ * designed to abort the tree walk as soon as a TRUE result is detected.)
+ */
+static bool
+foreign_expr_walker(Node *node, foreign_expr_cxt *context)
+{
+	bool		check_type = true;
+
+	if (node == NULL)
+		return false;
+
+	switch (nodeTag(node))
+	{
+		case T_Var:
+			{
+				/*
+				 * Var can be used if it is in the foreign table (we shouldn't
+				 * really see anything else in baserestrict clauses, but let's
+				 * check anyway).
+				 */
+				Var		   *var = (Var *) node;
+
+				if (var->varno != context->foreignrel->relid ||
+					var->varlevelsup != 0)
+					return true;
+			}
+			break;
+		case T_Const:
+			/* OK */
+			break;
+		case T_Param:
+			{
+				Param	   *p = (Param *) node;
+
+				/*
+				 * Only external parameters can be sent to remote.	(XXX This
+				 * needs to be improved, but at the point where this code
+				 * runs, we should only see PARAM_EXTERN Params anyway.)
+				 */
+				if (p->paramkind != PARAM_EXTERN)
+					return true;
+
+				/*
+				 * Report IDs of PARAM_EXTERN Params.  We don't bother to
+				 * eliminate duplicate list elements here; classifyConditions
+				 * will do that.
+				 */
+				context->param_numbers = lappend_int(context->param_numbers,
+													 p->paramid);
+			}
+			break;
+		case T_ArrayRef:
+			{
+				ArrayRef   *ar = (ArrayRef *) node;;
+
+				/* Assignment should not be in restrictions. */
+				if (ar->refassgnexpr != NULL)
+					return true;
+			}
+			break;
+		case T_FuncExpr:
+			{
+				/*
+				 * If function used by the expression is not built-in, it
+				 * can't be sent to remote because it might have incompatible
+				 * semantics on remote side.
+				 */
+				FuncExpr   *fe = (FuncExpr *) node;
+
+				if (!is_builtin(fe->funcid))
+					return true;
+			}
+			break;
+		case T_OpExpr:
+		case T_DistinctExpr:	/* struct-equivalent to OpExpr */
+			{
+				/*
+				 * Similarly, only built-in operators can be sent to remote.
+				 * (If the operator is, surely its underlying function is
+				 * too.)
+				 */
+				OpExpr	   *oe = (OpExpr *) node;
+
+				if (!is_builtin(oe->opno))
+					return true;
+			}
+			break;
+		case T_ScalarArrayOpExpr:
+			{
+				/*
+				 * Again, only built-in operators can be sent to remote.
+				 */
+				ScalarArrayOpExpr *oe = (ScalarArrayOpExpr *) node;
+
+				if (!is_builtin(oe->opno))
+					return true;
+			}
+			break;
+		case T_RelabelType:
+		case T_BoolExpr:
+		case T_NullTest:
+		case T_ArrayExpr:
+			/* OK */
+			break;
+		case T_List:
+
+			/*
+			 * We need only fall through to let expression_tree_walker scan
+			 * the list elements --- but don't apply exprType() to the list.
+			 */
+			check_type = false;
+			break;
+		default:
+
+			/*
+			 * If it's anything else, assume it's unsafe.  This list can be
+			 * expanded later, but don't forget to add deparse support below.
+			 */
+			return true;
+	}
+
+	/*
+	 * If result type of given expression is not built-in, it can't be sent to
+	 * remote because it might have incompatible semantics on remote side.
+	 */
+	if (check_type && !is_builtin(exprType(node)))
+		return true;
+
+	/* Recurse to examine sub-nodes */
+	return expression_tree_walker(node, foreign_expr_walker, context);
+}
+
+/*
+ * Return true if given object is one of PostgreSQL's built-in objects.
+ *
+ * XXX there is a problem with this, which is that the set of built-in
+ * objects expands over time.  Something that is built-in to us might not
+ * be known to the remote server, if it's of an older version.  But keeping
+ * track of that would be a huge exercise.
+ */
+static bool
+is_builtin(Oid oid)
+{
+	return (oid < FirstNormalObjectId);
+}
+
+
+/*
+ * Construct a simple SELECT statement that retrieves interesting columns
+ * of the specified foreign table, and append it to "buf".	The output
+ * contains just "SELECT ... FROM tablename".
+ *
+ * "Interesting" columns are those appearing in the rel's targetlist or
+ * in local_conds (conditions which can't be executed remotely).
+ */
+void
+deparseSimpleSql(StringInfo buf,
+				 PlannerInfo *root,
+				 RelOptInfo *baserel,
+				 List *local_conds)
+{
+	RangeTblEntry *rte = root->simple_rte_array[baserel->relid];
+	Bitmapset  *attrs_used = NULL;
+	bool		first;
+	AttrNumber	attr;
+	ListCell   *lc;
+
+	/* Collect all the attributes needed for joins or final output. */
+	pull_varattnos((Node *) baserel->reltargetlist, baserel->relid,
+				   &attrs_used);
+
+	/* Add all the attributes used by local_conds. */
+	foreach(lc, local_conds)
+	{
+		RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+
+		pull_varattnos((Node *) rinfo->clause, baserel->relid,
+					   &attrs_used);
+	}
+
+	/*
+	 * Construct SELECT list
+	 *
+	 * We list attributes in order of the foreign table's columns, but replace
+	 * any attributes that need not be fetched with NULL constants. (We can't
+	 * just omit such attributes, or we'll lose track of which columns are
+	 * which at runtime.)  Note however that any dropped columns are ignored.
+	 */
+	appendStringInfo(buf, "SELECT ");
+	first = true;
+	for (attr = 1; attr <= baserel->max_attr; attr++)
+	{
+		/* Ignore dropped attributes. */
+		if (get_rte_attribute_is_dropped(rte, attr))
+			continue;
+
+		if (!first)
+			appendStringInfo(buf, ", ");
+		first = false;
+
+		if (bms_is_member(attr - FirstLowInvalidHeapAttributeNumber,
+						  attrs_used))
+			deparseColumnRef(buf, baserel->relid, attr, root);
+		else
+			appendStringInfo(buf, "NULL");
+	}
+
+	/* Don't generate bad syntax if no undropped columns */
+	if (first)
+		appendStringInfo(buf, "NULL");
+
+	/*
+	 * Construct FROM clause
+	 */
+	appendStringInfo(buf, " FROM ");
+	deparseRelation(buf, rte->relid);
+}
+
+/*
+ * Deparse WHERE clauses in given list of RestrictInfos and append them to buf.
+ *
+ * If no WHERE clause already exists in the buffer, is_first should be true.
+ */
+void
+appendWhereClause(StringInfo buf,
+				  bool is_first,
+				  List *exprs,
+				  PlannerInfo *root)
+{
+	ListCell   *lc;
+
+	foreach(lc, exprs)
+	{
+		RestrictInfo *ri = (RestrictInfo *) lfirst(lc);
+
+		/* Connect expressions with "AND" and parenthesize each condition. */
+		if (is_first)
+			appendStringInfo(buf, " WHERE ");
+		else
+			appendStringInfo(buf, " AND ");
+
+		appendStringInfoChar(buf, '(');
+		deparseExpr(buf, ri->clause, root);
+		appendStringInfoChar(buf, ')');
+
+		is_first = false;
+	}
+}
+
+/*
+ * Construct SELECT statement to acquire sample rows of given relation.
+ *
+ * Note: command is appended to whatever might be in buf already.
+ */
+void
+deparseAnalyzeSql(StringInfo buf, Relation rel)
+{
+	Oid			relid = RelationGetRelid(rel);
+	TupleDesc	tupdesc = RelationGetDescr(rel);
+	int			i;
+	char	   *colname;
+	List	   *options;
+	ListCell   *lc;
+	bool		first = true;
+
+	appendStringInfo(buf, "SELECT ");
+	for (i = 0; i < tupdesc->natts; i++)
+	{
+		/* Ignore dropped columns. */
+		if (tupdesc->attrs[i]->attisdropped)
+			continue;
+
+		/* Use attribute name or column_name option. */
+		colname = NameStr(tupdesc->attrs[i]->attname);
+		options = GetForeignColumnOptions(relid, i + 1);
+
+		foreach(lc, options)
+		{
+			DefElem    *def = (DefElem *) lfirst(lc);
+
+			if (strcmp(def->defname, "column_name") == 0)
+			{
+				colname = defGetString(def);
+				break;
+			}
+		}
+
+		if (!first)
+			appendStringInfo(buf, ", ");
+		appendStringInfoString(buf, quote_identifier(colname));
+		first = false;
+	}
+
+	/* Don't generate bad syntax for zero-column relation. */
+	if (first)
+		appendStringInfo(buf, "NULL");
+
+	/*
+	 * Construct FROM clause
+	 */
+	appendStringInfo(buf, " FROM ");
+	deparseRelation(buf, relid);
+}
+
+/*
+ * Construct name to use for given column, and emit it into buf.
+ * If it has a column_name FDW option, use that instead of attribute name.
+ */
+static void
+deparseColumnRef(StringInfo buf, int varno, int varattno, PlannerInfo *root)
+{
+	RangeTblEntry *rte;
+	char	   *colname = NULL;
+	List	   *options;
+	ListCell   *lc;
+
+	/* varno must not be any of OUTER_VAR, INNER_VAR and INDEX_VAR. */
+	Assert(varno >= 1 && varno <= root->simple_rel_array_size);
+
+	/* Get RangeTblEntry from array in PlannerInfo. */
+	rte = root->simple_rte_array[varno];
+
+	/*
+	 * If it's a column of a foreign table, and it has the column_name FDW
+	 * option, use that value.
+	 */
+	options = GetForeignColumnOptions(rte->relid, varattno);
+	foreach(lc, options)
+	{
+		DefElem    *def = (DefElem *) lfirst(lc);
+
+		if (strcmp(def->defname, "column_name") == 0)
+		{
+			colname = defGetString(def);
+			break;
+		}
+	}
+
+	/*
+	 * If it's a column of a regular table or it doesn't have column_name FDW
+	 * option, use attribute name.
+	 */
+	if (colname == NULL)
+		colname = get_relid_attribute_name(rte->relid, varattno);
+
+	appendStringInfoString(buf, quote_identifier(colname));
+}
+
+/*
+ * Append remote name of specified foreign table to buf.
+ * Use value of table_name FDW option (if any) instead of relation's name.
+ * Similarly, schema_name FDW option overrides schema name.
+ */
+static void
+deparseRelation(StringInfo buf, Oid relid)
+{
+	ForeignTable *table;
+	const char *nspname = NULL;
+	const char *relname = NULL;
+	ListCell   *lc;
+
+	/* obtain additional catalog information. */
+	table = GetForeignTable(relid);
+
+	/*
+	 * Use value of FDW options if any, instead of the name of object itself.
+	 */
+	foreach(lc, table->options)
+	{
+		DefElem    *def = (DefElem *) lfirst(lc);
+
+		if (strcmp(def->defname, "schema_name") == 0)
+			nspname = defGetString(def);
+		else if (strcmp(def->defname, "table_name") == 0)
+			relname = defGetString(def);
+	}
+
+	if (nspname == NULL)
+		nspname = get_namespace_name(get_rel_namespace(relid));
+	if (relname == NULL)
+		relname = get_rel_name(relid);
+
+	appendStringInfo(buf, "%s.%s",
+					 quote_identifier(nspname), quote_identifier(relname));
+}
+
+/*
+ * Append a SQL string literal representing "val" to buf.
+ */
+static void
+deparseStringLiteral(StringInfo buf, const char *val)
+{
+	const char *valptr;
+
+	/*
+	 * Rather than making assumptions about the remote server's value of
+	 * standard_conforming_strings, always use E'foo' syntax if there are any
+	 * backslashes.  This will fail on remote servers before 8.1, but those
+	 * are long out of support.
+	 */
+	if (strchr(val, '\\') != NULL)
+		appendStringInfoChar(buf, ESCAPE_STRING_SYNTAX);
+	appendStringInfoChar(buf, '\'');
+	for (valptr = val; *valptr; valptr++)
+	{
+		char		ch = *valptr;
+
+		if (SQL_STR_DOUBLE(ch, true))
+			appendStringInfoChar(buf, ch);
+		appendStringInfoChar(buf, ch);
+	}
+	appendStringInfoChar(buf, '\'');
+}
+
+/*
+ * Deparse given expression into buf.
+ *
+ * This function must support all the same node types that foreign_expr_walker
+ * accepts.
+ *
+ * Note: unlike ruleutils.c, we just use a simple hard-wired parenthesization
+ * scheme: anything more complex than a Var, Const, function call or cast
+ * should be self-parenthesized.
+ */
+static void
+deparseExpr(StringInfo buf, Expr *node, PlannerInfo *root)
+{
+	if (node == NULL)
+		return;
+
+	switch (nodeTag(node))
+	{
+		case T_Var:
+			deparseVar(buf, (Var *) node, root);
+			break;
+		case T_Const:
+			deparseConst(buf, (Const *) node, root);
+			break;
+		case T_Param:
+			deparseParam(buf, (Param *) node, root);
+			break;
+		case T_ArrayRef:
+			deparseArrayRef(buf, (ArrayRef *) node, root);
+			break;
+		case T_FuncExpr:
+			deparseFuncExpr(buf, (FuncExpr *) node, root);
+			break;
+		case T_OpExpr:
+			deparseOpExpr(buf, (OpExpr *) node, root);
+			break;
+		case T_DistinctExpr:
+			deparseDistinctExpr(buf, (DistinctExpr *) node, root);
+			break;
+		case T_ScalarArrayOpExpr:
+			deparseScalarArrayOpExpr(buf, (ScalarArrayOpExpr *) node, root);
+			break;
+		case T_RelabelType:
+			deparseRelabelType(buf, (RelabelType *) node, root);
+			break;
+		case T_BoolExpr:
+			deparseBoolExpr(buf, (BoolExpr *) node, root);
+			break;
+		case T_NullTest:
+			deparseNullTest(buf, (NullTest *) node, root);
+			break;
+		case T_ArrayExpr:
+			deparseArrayExpr(buf, (ArrayExpr *) node, root);
+			break;
+		default:
+			elog(ERROR, "unsupported expression type for deparse: %d",
+				 (int) nodeTag(node));
+			break;
+	}
+}
+
+/*
+ * Deparse given Var node into buf.
+ */
+static void
+deparseVar(StringInfo buf, Var *node, PlannerInfo *root)
+{
+	Assert(node->varlevelsup == 0);
+	deparseColumnRef(buf, node->varno, node->varattno, root);
+}
+
+/*
+ * Deparse given constant value into buf.
+ *
+ * This function has to be kept in sync with ruleutils.c's get_const_expr.
+ */
+static void
+deparseConst(StringInfo buf, Const *node, PlannerInfo *root)
+{
+	Oid			typoutput;
+	bool		typIsVarlena;
+	char	   *extval;
+	bool		isfloat = false;
+	bool		needlabel;
+
+	if (node->constisnull)
+	{
+		appendStringInfo(buf, "NULL");
+		appendStringInfo(buf, "::%s",
+						 format_type_with_typemod(node->consttype,
+												  node->consttypmod));
+		return;
+	}
+
+	getTypeOutputInfo(node->consttype,
+					  &typoutput, &typIsVarlena);
+	extval = OidOutputFunctionCall(typoutput, node->constvalue);
+
+	switch (node->consttype)
+	{
+		case INT2OID:
+		case INT4OID:
+		case INT8OID:
+		case OIDOID:
+		case FLOAT4OID:
+		case FLOAT8OID:
+		case NUMERICOID:
+			{
+				/*
+				 * No need to quote unless it's a special value such as 'NaN'.
+				 * See comments in get_const_expr().
+				 */
+				if (strspn(extval, "0123456789+-eE.") == strlen(extval))
+				{
+					if (extval[0] == '+' || extval[0] == '-')
+						appendStringInfo(buf, "(%s)", extval);
+					else
+						appendStringInfoString(buf, extval);
+					if (strcspn(extval, "eE.") != strlen(extval))
+						isfloat = true; /* it looks like a float */
+				}
+				else
+					appendStringInfo(buf, "'%s'", extval);
+			}
+			break;
+		case BITOID:
+		case VARBITOID:
+			appendStringInfo(buf, "B'%s'", extval);
+			break;
+		case BOOLOID:
+			if (strcmp(extval, "t") == 0)
+				appendStringInfoString(buf, "true");
+			else
+				appendStringInfoString(buf, "false");
+			break;
+		default:
+			deparseStringLiteral(buf, extval);
+			break;
+	}
+
+	/*
+	 * Append ::typename unless the constant will be implicitly typed as the
+	 * right type when it is read in.
+	 *
+	 * XXX this code has to be kept in sync with the behavior of the parser,
+	 * especially make_const.
+	 */
+	switch (node->consttype)
+	{
+		case BOOLOID:
+		case INT4OID:
+		case UNKNOWNOID:
+			needlabel = false;
+			break;
+		case NUMERICOID:
+			needlabel = !isfloat || (node->consttypmod >= 0);
+			break;
+		default:
+			needlabel = true;
+			break;
+	}
+	if (needlabel)
+		appendStringInfo(buf, "::%s",
+						 format_type_with_typemod(node->consttype,
+												  node->consttypmod));
+}
+
+/*
+ * Deparse given Param node into buf.
+ *
+ * We don't need to renumber the parameter ID, because the executor functions
+ * in postgres_fdw.c preserve the numbering of PARAM_EXTERN Params.
+ * (This might change soon.)
+ */
+static void
+deparseParam(StringInfo buf, Param *node, PlannerInfo *root)
+{
+	Assert(node->paramkind == PARAM_EXTERN);
+	appendStringInfo(buf, "$%d", node->paramid);
+}
+
+/*
+ * Deparse an array subscript expression.
+ */
+static void
+deparseArrayRef(StringInfo buf, ArrayRef *node, PlannerInfo *root)
+{
+	ListCell   *lowlist_item;
+	ListCell   *uplist_item;
+
+	/* Always parenthesize the expression. */
+	appendStringInfoChar(buf, '(');
+
+	/*
+	 * Deparse referenced array expression first.  If that expression includes
+	 * a cast, we have to parenthesize to prevent the array subscript from
+	 * being taken as typename decoration.	We can avoid that in the typical
+	 * case of subscripting a Var, but otherwise do it.
+	 */
+	if (IsA(node->refexpr, Var))
+		deparseExpr(buf, node->refexpr, root);
+	else
+	{
+		appendStringInfoChar(buf, '(');
+		deparseExpr(buf, node->refexpr, root);
+		appendStringInfoChar(buf, ')');
+	}
+
+	/* Deparse subscript expressions. */
+	lowlist_item = list_head(node->reflowerindexpr);	/* could be NULL */
+	foreach(uplist_item, node->refupperindexpr)
+	{
+		appendStringInfoChar(buf, '[');
+		if (lowlist_item)
+		{
+			deparseExpr(buf, lfirst(lowlist_item), root);
+			appendStringInfoChar(buf, ':');
+			lowlist_item = lnext(lowlist_item);
+		}
+		deparseExpr(buf, lfirst(uplist_item), root);
+		appendStringInfoChar(buf, ']');
+	}
+
+	appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Deparse given node which represents a function call into buf.
+ *
+ * Here not only explicit function calls and explicit casts but also implicit
+ * casts are deparsed to avoid problems caused by different cast settings
+ * between local and remote.
+ *
+ * Function name is always qualified by schema name to avoid problems caused
+ * by different setting of search_path on remote side.
+ */
+static void
+deparseFuncExpr(StringInfo buf, FuncExpr *node, PlannerInfo *root)
+{
+	HeapTuple	proctup;
+	Form_pg_proc procform;
+	const char *proname;
+	const char *schemaname;
+	bool		use_variadic;
+	bool		first;
+	ListCell   *arg;
+
+	proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(node->funcid));
+	if (!HeapTupleIsValid(proctup))
+		elog(ERROR, "cache lookup failed for function %u", node->funcid);
+	procform = (Form_pg_proc) GETSTRUCT(proctup);
+	proname = NameStr(procform->proname);
+
+	/* Check if need to print VARIADIC (cf. ruleutils.c) */
+	if (OidIsValid(procform->provariadic))
+	{
+		if (procform->provariadic != ANYOID)
+			use_variadic = true;
+		else
+			use_variadic = node->funcvariadic;
+	}
+	else
+		use_variadic = false;
+
+	/* Deparse the function name ... */
+	schemaname = get_namespace_name(procform->pronamespace);
+	appendStringInfo(buf, "%s.%s(",
+					 quote_identifier(schemaname),
+					 quote_identifier(proname));
+	/* ... and all the arguments */
+	first = true;
+	foreach(arg, node->args)
+	{
+		if (!first)
+			appendStringInfoString(buf, ", ");
+		if (use_variadic && lnext(arg) == NULL)
+			appendStringInfoString(buf, "VARIADIC ");
+		deparseExpr(buf, (Expr *) lfirst(arg), root);
+		first = false;
+	}
+	appendStringInfoChar(buf, ')');
+
+	ReleaseSysCache(proctup);
+}
+
+/*
+ * Deparse given operator expression into buf.	To avoid problems around
+ * priority of operations, we always parenthesize the arguments.  Also we use
+ * OPERATOR(schema.operator) notation to determine remote operator exactly.
+ */
+static void
+deparseOpExpr(StringInfo buf, OpExpr *node, PlannerInfo *root)
+{
+	HeapTuple	tuple;
+	Form_pg_operator form;
+	const char *opnspname;
+	char	   *opname;
+	char		oprkind;
+	ListCell   *arg;
+
+	/* Retrieve information about the operator from system catalog. */
+	tuple = SearchSysCache1(OPEROID, ObjectIdGetDatum(node->opno));
+	if (!HeapTupleIsValid(tuple))
+		elog(ERROR, "cache lookup failed for operator %u", node->opno);
+	form = (Form_pg_operator) GETSTRUCT(tuple);
+
+	opnspname = quote_identifier(get_namespace_name(form->oprnamespace));
+	/* opname is not a SQL identifier, so we don't need to quote it. */
+	opname = NameStr(form->oprname);
+	oprkind = form->oprkind;
+
+	/* Sanity check. */
+	Assert((oprkind == 'r' && list_length(node->args) == 1) ||
+		   (oprkind == 'l' && list_length(node->args) == 1) ||
+		   (oprkind == 'b' && list_length(node->args) == 2));
+
+	/* Always parenthesize the expression. */
+	appendStringInfoChar(buf, '(');
+
+	/* Deparse left operand. */
+	if (oprkind == 'r' || oprkind == 'b')
+	{
+		arg = list_head(node->args);
+		deparseExpr(buf, lfirst(arg), root);
+		appendStringInfoChar(buf, ' ');
+	}
+
+	/* Deparse fully qualified operator name. */
+	appendStringInfo(buf, "OPERATOR(%s.%s)", opnspname, opname);
+
+	/* Deparse right operand. */
+	if (oprkind == 'l' || oprkind == 'b')
+	{
+		arg = list_tail(node->args);
+		appendStringInfoChar(buf, ' ');
+		deparseExpr(buf, lfirst(arg), root);
+	}
+
+	appendStringInfoChar(buf, ')');
+
+	ReleaseSysCache(tuple);
+}
+
+/*
+ * Deparse IS DISTINCT FROM.
+ */
+static void
+deparseDistinctExpr(StringInfo buf, DistinctExpr *node, PlannerInfo *root)
+{
+	Assert(list_length(node->args) == 2);
+
+	appendStringInfoChar(buf, '(');
+	deparseExpr(buf, linitial(node->args), root);
+	appendStringInfo(buf, " IS DISTINCT FROM ");
+	deparseExpr(buf, lsecond(node->args), root);
+	appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Deparse given ScalarArrayOpExpr expression into buf.  To avoid problems
+ * around priority of operations, we always parenthesize the arguments.  Also
+ * we use OPERATOR(schema.operator) notation to determine remote operator
+ * exactly.
+ */
+static void
+deparseScalarArrayOpExpr(StringInfo buf,
+						 ScalarArrayOpExpr *node,
+						 PlannerInfo *root)
+{
+	HeapTuple	tuple;
+	Form_pg_operator form;
+	const char *opnspname;
+	char	   *opname;
+	Expr	   *arg1;
+	Expr	   *arg2;
+
+	/* Retrieve information about the operator from system catalog. */
+	tuple = SearchSysCache1(OPEROID, ObjectIdGetDatum(node->opno));
+	if (!HeapTupleIsValid(tuple))
+		elog(ERROR, "cache lookup failed for operator %u", node->opno);
+	form = (Form_pg_operator) GETSTRUCT(tuple);
+
+	opnspname = quote_identifier(get_namespace_name(form->oprnamespace));
+	/* opname is not a SQL identifier, so we don't need to quote it. */
+	opname = NameStr(form->oprname);
+
+	/* Sanity check. */
+	Assert(list_length(node->args) == 2);
+
+	/* Always parenthesize the expression. */
+	appendStringInfoChar(buf, '(');
+
+	/* Deparse left operand. */
+	arg1 = linitial(node->args);
+	deparseExpr(buf, arg1, root);
+
+	/* Deparse fully qualified operator name plus decoration. */
+	appendStringInfo(buf, " OPERATOR(%s.%s) %s (",
+					 opnspname, opname, node->useOr ? "ANY" : "ALL");
+
+	/* Deparse right operand. */
+	arg2 = lsecond(node->args);
+	deparseExpr(buf, arg2, root);
+
+	appendStringInfoChar(buf, ')');
+
+	/* Always parenthesize the expression. */
+	appendStringInfoChar(buf, ')');
+
+	ReleaseSysCache(tuple);
+}
+
+/*
+ * Deparse a RelabelType (binary-compatible cast) node.
+ */
+static void
+deparseRelabelType(StringInfo buf, RelabelType *node, PlannerInfo *root)
+{
+	deparseExpr(buf, node->arg, root);
+	appendStringInfo(buf, "::%s",
+					 format_type_with_typemod(node->resulttype,
+											  node->resulttypmod));
+}
+
+/*
+ * Deparse a BoolExpr node.
+ *
+ * Note: by the time we get here, AND and OR expressions have been flattened
+ * into N-argument form, so we'd better be prepared to deal with that.
+ */
+static void
+deparseBoolExpr(StringInfo buf, BoolExpr *node, PlannerInfo *root)
+{
+	const char *op = NULL;		/* keep compiler quiet */
+	bool		first;
+	ListCell   *lc;
+
+	switch (node->boolop)
+	{
+		case AND_EXPR:
+			op = "AND";
+			break;
+		case OR_EXPR:
+			op = "OR";
+			break;
+		case NOT_EXPR:
+			appendStringInfo(buf, "(NOT ");
+			deparseExpr(buf, linitial(node->args), root);
+			appendStringInfoChar(buf, ')');
+			return;
+	}
+
+	appendStringInfoChar(buf, '(');
+	first = true;
+	foreach(lc, node->args)
+	{
+		if (!first)
+			appendStringInfo(buf, " %s ", op);
+		deparseExpr(buf, (Expr *) lfirst(lc), root);
+		first = false;
+	}
+	appendStringInfoChar(buf, ')');
+}
+
+/*
+ * Deparse IS [NOT] NULL expression.
+ */
+static void
+deparseNullTest(StringInfo buf, NullTest *node, PlannerInfo *root)
+{
+	appendStringInfoChar(buf, '(');
+	deparseExpr(buf, node->arg, root);
+	if (node->nulltesttype == IS_NULL)
+		appendStringInfo(buf, " IS NULL)");
+	else
+		appendStringInfo(buf, " IS NOT NULL)");
+}
+
+/*
+ * Deparse ARRAY[...] construct.
+ */
+static void
+deparseArrayExpr(StringInfo buf, ArrayExpr *node, PlannerInfo *root)
+{
+	bool		first = true;
+	ListCell   *lc;
+
+	appendStringInfo(buf, "ARRAY[");
+	foreach(lc, node->elements)
+	{
+		if (!first)
+			appendStringInfo(buf, ", ");
+		deparseExpr(buf, lfirst(lc), root);
+		first = false;
+	}
+	appendStringInfoChar(buf, ']');
+
+	/* If the array is empty, we need an explicit cast to the array type. */
+	if (node->elements == NIL)
+		appendStringInfo(buf, "::%s",
+						 format_type_with_typemod(node->array_typeid, -1));
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
new file mode 100644
index 0000000000000000000000000000000000000000..253cdca11a361c4dc70b2a28ddf6a1c9b1d24824
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -0,0 +1,704 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+  OPTIONS (dbname 'contrib_regression');
+CREATE USER MAPPING FOR public SERVER testserver1
+	OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+-- ===================================================================
+-- 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,
+	c5 timestamp,
+	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)
+);
+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;
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+	c0 int,
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	c4 timestamptz,
+	c5 timestamp,
+	c6 varchar(10),
+	c7 char(10),
+	c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+	c0 int,
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	c4 timestamptz,
+	c5 timestamp,
+	c6 varchar(10),
+	c7 char(10),
+	c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN c0;
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl, krbsrvname and gsslib are omitted because they depend on
+-- configure options
+ALTER SERVER testserver1 OPTIONS (
+	use_remote_explain 'false',
+	fdw_startup_cost '123.456',
+	fdw_tuple_cost '0.123',
+	service 'value',
+	connect_timeout 'value',
+	dbname 'value',
+	host 'value',
+	hostaddr 'value',
+	port 'value',
+	--client_encoding 'value',
+	application_name 'value',
+	--fallback_application_name 'value',
+	keepalives 'value',
+	keepalives_idle 'value',
+	keepalives_interval 'value',
+	-- requiressl 'value',
+	sslcompression 'value',
+	sslmode 'value',
+	sslcert 'value',
+	sslkey 'value',
+	sslrootcert 'value',
+	sslcrl 'value'
+	--requirepeer 'value',
+	-- krbsrvname 'value',
+	-- gsslib 'value',
+	--replication 'value'
+);
+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)
+
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote_explain mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_explain 'true');
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table, with/without alias
+EXPLAIN (COSTS false) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+           QUERY PLAN            
+---------------------------------
+ Limit
+   ->  Sort
+         Sort Key: c3, c1
+         ->  Foreign Scan on ft1
+(4 rows)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1  | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 |  1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1  | 1          | foo
+ 102 |  2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2  | 2          | foo
+ 103 |  3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3  | 3          | foo
+ 104 |  4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4  | 4          | foo
+ 105 |  5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5  | 5          | foo
+ 106 |  6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6  | 6          | foo
+ 107 |  7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7  | 7          | foo
+ 108 |  8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8  | 8          | foo
+ 109 |  9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9  | 9          | foo
+ 110 |  0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0  | 0          | foo
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+                                     QUERY PLAN                                      
+-------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   ->  Sort
+         Output: c1, c2, c3, c4, c5, c6, c7, c8
+         Sort Key: t1.c3, t1.c1
+         ->  Foreign Scan on public.ft1 t1
+               Output: c1, c2, c3, c4, c5, c6, c7, c8
+               Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1  | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 |  1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1  | 1          | foo
+ 102 |  2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2  | 2          | foo
+ 103 |  3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3  | 3          | foo
+ 104 |  4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4  | 4          | foo
+ 105 |  5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5  | 5          | foo
+ 106 |  6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6  | 6          | foo
+ 107 |  7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7  | 7          | foo
+ 108 |  8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8  | 8          | foo
+ 109 |  9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9  | 9          | foo
+ 110 |  0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0  | 0          | foo
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+                                                                                                     QUERY PLAN                                                                                                      
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 OPERATOR(pg_catalog.>=) '1'::bpchar)) AND (("C 1" OPERATOR(pg_catalog.=) 101)) AND ((c6::text OPERATOR(pg_catalog.=) '1'::text))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1  | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 |  1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1  | 1          | 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
+  7 |  7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7  | 7          | foo
+  8 |  8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8  | 8          | foo
+  9 |  9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9  | 9          | foo
+ 10 |  0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0  | 0          | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+  c1  | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 |  0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0  | 0          | foo
+(1 row)
+
+-- 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;
+ c1 | c2 |  c3   |              c4              
+----+----+-------+------------------------------
+  1 |  1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+  2 |  2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+  3 |  3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+  4 |  4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+  5 |  5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+  6 |  6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+  7 |  7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+  8 |  8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+  9 |  9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 |  0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column? 
+----------+----------
+ fixed    | 
+(1 row)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+    LEFTARG = int,
+    RIGHTARG = int,
+    PROCEDURE = int4eq,
+    COMMUTATOR = ===,
+    NEGATOR = !==
+);
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+                               QUERY PLAN                                
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2;
+                               QUERY PLAN                                
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Filter: (t1.c1 === t1.c2)
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+                                                            QUERY PLAN                                                             
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) pg_catalog.abs(c2)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+                                                    QUERY PLAN                                                     
+-------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) c2))
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+                                                                       QUERY PLAN                                                                       
+--------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 100)) AND ((c2 OPERATOR(pg_catalog.=) 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 IS NULL;        -- NullTest
+                                           QUERY PLAN                                            
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL;    -- NullTest
+                                             QUERY PLAN                                              
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+                                                                                      QUERY PLAN                                                                                      
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((pg_catalog.round(pg_catalog."numeric"(pg_catalog.abs("C 1")), 0) OPERATOR(pg_catalog.=) 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = -c1;          -- OpExpr(l)
+                                                                  QUERY PLAN                                                                   
+-----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) (OPERATOR(pg_catalog.-) "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE 1 = c1!;           -- OpExpr(r)
+                                                                             QUERY PLAN                                                                              
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((1::numeric OPERATOR(pg_catalog.=) (pg_catalog.int8("C 1") OPERATOR(pg_catalog.!))))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+                                                                 QUERY PLAN                                                                 
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+                                                                             QUERY PLAN                                                                              
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) ANY (ARRAY[c2, 1, ("C 1" OPERATOR(pg_catalog.+) 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- ArrayRef
+                                                                QUERY PLAN                                                                 
+-------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar';  -- check special chars
+                                                               QUERY PLAN                                                               
+----------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6::text OPERATOR(pg_catalog.=) E'foo''s\\bar'::text))
+(3 rows)
+
+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 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
+   Output: t1.c3, t2.c3
+   ->  Foreign Scan on public.ft1 t1
+         Output: t1.c3
+         Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+   ->  Foreign Scan on public.ft2 t2
+         Output: t2.c3
+         Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 2))
+(8 rows)
+
+EXECUTE st1(1, 1);
+  c3   |  c3   
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+  c3   |  c3   
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- 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 EXTRACT(dow FROM c4) = 6) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st2(10, 20);
+                                                                  QUERY PLAN                                                                  
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+   Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+   Sort Key: t1.c1
+   ->  Nested Loop Semi Join
+         Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+         Join Filter: (t1.c3 = t2.c3)
+         ->  Foreign Scan on public.ft1 t1
+               Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+               Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.<) 20))
+         ->  Materialize
+               Output: t2.c3
+               ->  Foreign Scan on public.ft2 t2
+                     Output: t2.c3
+                     Filter: (date_part('dow'::text, t2.c4) = 6::double precision)
+                     Remote SQL: SELECT NULL, NULL, c3, c4, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.>) 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 |  6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6  | 6          | foo
+(1 row)
+
+EXECUTE st1(101, 101);
+  c3   |  c3   
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND EXTRACT(dow FROM c5) = 6) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st3(10, 20);
+                                                                                                               QUERY PLAN                                                                                                                
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+   Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+   Sort Key: t1.c1
+   ->  Nested Loop Semi Join
+         Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+         Join Filter: (t1.c3 = t2.c3)
+         ->  Foreign Scan on public.ft1 t1
+               Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+               Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.<) 20))
+         ->  Materialize
+               Output: t2.c3
+               ->  Foreign Scan on public.ft2 t2
+                     Output: t2.c3
+                     Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.>) 10)) AND ((pg_catalog.date_part('dow'::text, c5) OPERATOR(pg_catalog.=) 6::double precision))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 |  6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6  | 6          | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 23 |  3 | 00023 | Sat Jan 24 00:00:00 1970 PST | Sat Jan 24 00:00:00 1970 | 3  | 3          | foo
+(1 row)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                    
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+                                                    QUERY PLAN                                                     
+-------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) $1))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    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" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    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" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    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" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    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" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    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" WHERE (("C 1" OPERATOR(pg_catalog.=) 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+                                                    QUERY PLAN                                                     
+-------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+   Output: c1, c2, c3, c4, c5, c6, c7, c8
+   Filter: (t1.c8 = $1)
+   Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(pg_catalog.=) $2))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ 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
+(1 row)
+
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+-- ===================================================================
+-- used in pl/pgsql function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+	v_c1 int;
+BEGIN
+    SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+    PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+    RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ 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"
+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  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+  1 |  1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1  | 1          | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT;          -- ERROR
+ERROR:  syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+        ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+  2 |  2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2  | 2          | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0;  -- ERROR
+ERROR:  division by zero
+CONTEXT:  Remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 OPERATOR(pg_catalog./) ("C 1" OPERATOR(pg_catalog.-) 1)) OPERATOR(pg_catalog.>) 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+  3 |  3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3  | 3          | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ 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
+(1 row)
+
+COMMIT;
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
new file mode 100644
index 0000000000000000000000000000000000000000..3a3ae226276c3f1cb1576b0c7526e05dbc787d83
--- /dev/null
+++ b/contrib/postgres_fdw/option.c
@@ -0,0 +1,293 @@
+/*-------------------------------------------------------------------------
+ *
+ * option.c
+ *		  FDW option handling for postgres_fdw
+ *
+ * Portions Copyright (c) 2012-2013, PostgreSQL Global Development Group
+ *
+ * IDENTIFICATION
+ *		  contrib/postgres_fdw/option.c
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "postgres_fdw.h"
+
+#include "access/reloptions.h"
+#include "catalog/pg_foreign_server.h"
+#include "catalog/pg_foreign_table.h"
+#include "catalog/pg_user_mapping.h"
+#include "commands/defrem.h"
+
+
+/*
+ * Describes the valid options for objects that this wrapper uses.
+ */
+typedef struct PgFdwOption
+{
+	const char *keyword;
+	Oid			optcontext;		/* OID of catalog in which option may appear */
+	bool		is_libpq_opt;	/* true if it's used in libpq */
+} PgFdwOption;
+
+/*
+ * Valid options for postgres_fdw.
+ * Allocated and filled in InitPgFdwOptions.
+ */
+static PgFdwOption *postgres_fdw_options;
+
+/*
+ * Valid options for libpq.
+ * Allocated and filled in InitPgFdwOptions.
+ */
+static PQconninfoOption *libpq_options;
+
+/*
+ * Helper functions
+ */
+static void InitPgFdwOptions(void);
+static bool is_valid_option(const char *keyword, Oid context);
+static bool is_libpq_option(const char *keyword);
+
+
+/*
+ * Validate the generic options given to a FOREIGN DATA WRAPPER, SERVER,
+ * USER MAPPING or FOREIGN TABLE that uses postgres_fdw.
+ *
+ * Raise an ERROR if the option or its value is considered invalid.
+ */
+extern Datum postgres_fdw_validator(PG_FUNCTION_ARGS);
+
+PG_FUNCTION_INFO_V1(postgres_fdw_validator);
+
+Datum
+postgres_fdw_validator(PG_FUNCTION_ARGS)
+{
+	List	   *options_list = untransformRelOptions(PG_GETARG_DATUM(0));
+	Oid			catalog = PG_GETARG_OID(1);
+	ListCell   *cell;
+
+	/* Build our options lists if we didn't yet. */
+	InitPgFdwOptions();
+
+	/*
+	 * Check that only options supported by postgres_fdw, and allowed for the
+	 * current object type, are given.
+	 */
+	foreach(cell, options_list)
+	{
+		DefElem    *def = (DefElem *) lfirst(cell);
+
+		if (!is_valid_option(def->defname, catalog))
+		{
+			/*
+			 * Unknown option specified, complain about it. Provide a hint
+			 * with list of valid options for the object.
+			 */
+			PgFdwOption *opt;
+			StringInfoData buf;
+
+			initStringInfo(&buf);
+			for (opt = postgres_fdw_options; opt->keyword; opt++)
+			{
+				if (catalog == opt->optcontext)
+					appendStringInfo(&buf, "%s%s", (buf.len > 0) ? ", " : "",
+									 opt->keyword);
+			}
+
+			ereport(ERROR,
+					(errcode(ERRCODE_FDW_INVALID_OPTION_NAME),
+					 errmsg("invalid option \"%s\"", def->defname),
+					 errhint("Valid options in this context are: %s",
+							 buf.data)));
+		}
+
+		/*
+		 * Validate option value, when we can do so without any context.
+		 */
+		if (strcmp(def->defname, "use_remote_explain") == 0)
+		{
+			/* use_remote_explain accepts only boolean values */
+			(void) defGetBoolean(def);
+		}
+		else if (strcmp(def->defname, "fdw_startup_cost") == 0 ||
+				 strcmp(def->defname, "fdw_tuple_cost") == 0)
+		{
+			/* these must have a non-negative numeric value */
+			double		val;
+			char	   *endp;
+
+			val = strtod(defGetString(def), &endp);
+			if (*endp || val < 0)
+				ereport(ERROR,
+						(errcode(ERRCODE_SYNTAX_ERROR),
+						 errmsg("%s requires a non-negative numeric value",
+								def->defname)));
+		}
+	}
+
+	PG_RETURN_VOID();
+}
+
+/*
+ * Initialize option lists.
+ */
+static void
+InitPgFdwOptions(void)
+{
+	int			num_libpq_opts;
+	PQconninfoOption *lopt;
+	PgFdwOption *popt;
+
+	/* non-libpq FDW-specific FDW options */
+	static const PgFdwOption non_libpq_options[] = {
+		{"schema_name", ForeignTableRelationId, false},
+		{"table_name", ForeignTableRelationId, false},
+		{"column_name", AttributeRelationId, false},
+		/* use_remote_explain is available on both server and table */
+		{"use_remote_explain", ForeignServerRelationId, false},
+		{"use_remote_explain", ForeignTableRelationId, false},
+		/* cost factors */
+		{"fdw_startup_cost", ForeignServerRelationId, false},
+		{"fdw_tuple_cost", ForeignServerRelationId, false},
+		{NULL, InvalidOid, false}
+	};
+
+	/* Prevent redundant initialization. */
+	if (postgres_fdw_options)
+		return;
+
+	/*
+	 * Get list of valid libpq options.
+	 *
+	 * To avoid unnecessary work, we get the list once and use it throughout
+	 * the lifetime of this backend process.  We don't need to care about
+	 * memory context issues, because PQconndefaults allocates with malloc.
+	 */
+	libpq_options = PQconndefaults();
+	if (!libpq_options)			/* assume reason for failure is OOM */
+		ereport(ERROR,
+				(errcode(ERRCODE_FDW_OUT_OF_MEMORY),
+				 errmsg("out of memory"),
+			 errdetail("could not get libpq's default connection options")));
+
+	/* Count how many libpq options are available. */
+	num_libpq_opts = 0;
+	for (lopt = libpq_options; lopt->keyword; lopt++)
+		num_libpq_opts++;
+
+	/*
+	 * Construct an array which consists of all valid options for
+	 * postgres_fdw, by appending FDW-specific options to libpq options.
+	 *
+	 * We use plain malloc here to allocate postgres_fdw_options because it
+	 * lives as long as the backend process does.  Besides, keeping
+	 * libpq_options in memory allows us to avoid copying every keyword
+	 * string.
+	 */
+	postgres_fdw_options = (PgFdwOption *)
+		malloc(sizeof(PgFdwOption) * num_libpq_opts +
+			   sizeof(non_libpq_options));
+	if (postgres_fdw_options == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_FDW_OUT_OF_MEMORY),
+				 errmsg("out of memory")));
+
+	popt = postgres_fdw_options;
+	for (lopt = libpq_options; lopt->keyword; lopt++)
+	{
+		/* Hide debug options, as well as settings we override internally. */
+		if (strchr(lopt->dispchar, 'D') ||
+			strcmp(lopt->keyword, "fallback_application_name") == 0 ||
+			strcmp(lopt->keyword, "client_encoding") == 0)
+			continue;
+
+		/* We don't have to copy keyword string, as described above. */
+		popt->keyword = lopt->keyword;
+
+		/*
+		 * "user" and any secret options are allowed only on user mappings.
+		 * Everything else is a server option.
+		 */
+		if (strcmp(lopt->keyword, "user") == 0 || strchr(lopt->dispchar, '*'))
+			popt->optcontext = UserMappingRelationId;
+		else
+			popt->optcontext = ForeignServerRelationId;
+		popt->is_libpq_opt = true;
+
+		popt++;
+	}
+
+	/* Append FDW-specific options and dummy terminator. */
+	memcpy(popt, non_libpq_options, sizeof(non_libpq_options));
+}
+
+/*
+ * Check whether the given option is one of the valid postgres_fdw options.
+ * context is the Oid of the catalog holding the object the option is for.
+ */
+static bool
+is_valid_option(const char *keyword, Oid context)
+{
+	PgFdwOption *opt;
+
+	Assert(postgres_fdw_options);		/* must be initialized already */
+
+	for (opt = postgres_fdw_options; opt->keyword; opt++)
+	{
+		if (context == opt->optcontext && strcmp(opt->keyword, keyword) == 0)
+			return true;
+	}
+
+	return false;
+}
+
+/*
+ * Check whether the given option is one of the valid libpq options.
+ */
+static bool
+is_libpq_option(const char *keyword)
+{
+	PgFdwOption *opt;
+
+	Assert(postgres_fdw_options);		/* must be initialized already */
+
+	for (opt = postgres_fdw_options; opt->keyword; opt++)
+	{
+		if (opt->is_libpq_opt && strcmp(opt->keyword, keyword) == 0)
+			return true;
+	}
+
+	return false;
+}
+
+/*
+ * Generate key-value arrays which include only libpq options from the
+ * given list (which can contain any kind of options).	Caller must have
+ * allocated large-enough arrays.  Returns number of options found.
+ */
+int
+ExtractConnectionOptions(List *defelems, const char **keywords,
+						 const char **values)
+{
+	ListCell   *lc;
+	int			i;
+
+	/* Build our options lists if we didn't yet. */
+	InitPgFdwOptions();
+
+	i = 0;
+	foreach(lc, defelems)
+	{
+		DefElem    *d = (DefElem *) lfirst(lc);
+
+		if (is_libpq_option(d->defname))
+		{
+			keywords[i] = d->defname;
+			values[i] = defGetString(d);
+			i++;
+		}
+	}
+	return i;
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0.sql b/contrib/postgres_fdw/postgres_fdw--1.0.sql
new file mode 100644
index 0000000000000000000000000000000000000000..a0f0fc1bf455a8935bd43e4f7535c1e1203a1c0a
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.0.sql
@@ -0,0 +1,18 @@
+/* contrib/postgres_fdw/postgres_fdw--1.0.sql */
+
+-- complain if script is sourced in psql, rather than via CREATE EXTENSION
+\echo Use "CREATE EXTENSION postgres_fdw" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_handler()
+RETURNS fdw_handler
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT;
+
+CREATE FUNCTION postgres_fdw_validator(text[], oid)
+RETURNS void
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT;
+
+CREATE FOREIGN DATA WRAPPER postgres_fdw
+  HANDLER postgres_fdw_handler
+  VALIDATOR postgres_fdw_validator;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
new file mode 100644
index 0000000000000000000000000000000000000000..0aef00b738dfeeede00e50aef31c538e6312bda2
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -0,0 +1,1400 @@
+/*-------------------------------------------------------------------------
+ *
+ * postgres_fdw.c
+ *		  Foreign-data wrapper for remote PostgreSQL servers
+ *
+ * Portions Copyright (c) 2012-2013, PostgreSQL Global Development Group
+ *
+ * IDENTIFICATION
+ *		  contrib/postgres_fdw/postgres_fdw.c
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "postgres_fdw.h"
+
+#include "access/htup_details.h"
+#include "commands/defrem.h"
+#include "commands/explain.h"
+#include "commands/vacuum.h"
+#include "foreign/fdwapi.h"
+#include "funcapi.h"
+#include "miscadmin.h"
+#include "optimizer/cost.h"
+#include "optimizer/pathnode.h"
+#include "optimizer/planmain.h"
+#include "parser/parsetree.h"
+#include "utils/lsyscache.h"
+#include "utils/memutils.h"
+
+
+PG_MODULE_MAGIC;
+
+/* Default CPU cost to start up a foreign query. */
+#define DEFAULT_FDW_STARTUP_COST	100.0
+
+/* Default CPU cost to process 1 row (above and beyond cpu_tuple_cost). */
+#define DEFAULT_FDW_TUPLE_COST		0.01
+
+/*
+ * FDW-specific planner information kept in RelOptInfo.fdw_private for a
+ * foreign table.  This information is collected by postgresGetForeignRelSize.
+ */
+typedef struct PgFdwRelationInfo
+{
+	/* XXX underdocumented, but a lot of this shouldn't be here anyway */
+	StringInfoData sql;
+	Cost		startup_cost;
+	Cost		total_cost;
+	List	   *remote_conds;
+	List	   *param_conds;
+	List	   *local_conds;
+	List	   *param_numbers;
+
+	/* Cached catalog information. */
+	ForeignTable *table;
+	ForeignServer *server;
+} PgFdwRelationInfo;
+
+/*
+ * Indexes of FDW-private information stored in fdw_private list.
+ *
+ * We store various information in ForeignScan.fdw_private to pass it from
+ * planner to executor.  Specifically there is:
+ *
+ * 1) SELECT statement text to be sent to the remote server
+ * 2) IDs of PARAM_EXEC Params used in the SELECT statement
+ *
+ * These items are indexed with the enum FdwPrivateIndex, so an item can be
+ * fetched with list_nth().  For example, to get the SELECT statement:
+ *		sql = strVal(list_nth(fdw_private, FdwPrivateSelectSql));
+ */
+enum FdwPrivateIndex
+{
+	/* SQL statement to execute remotely (as a String node) */
+	FdwPrivateSelectSql,
+
+	/* Integer list of param IDs of PARAM_EXEC Params used in SQL stmt */
+	FdwPrivateExternParamIds,
+
+	/* # of elements stored in the list fdw_private */
+	FdwPrivateNum
+};
+
+/*
+ * Execution state of a foreign scan using postgres_fdw.
+ */
+typedef struct PgFdwExecutionState
+{
+	Relation	rel;			/* relcache entry for the foreign table */
+	AttInMetadata *attinmeta;	/* attribute datatype conversion metadata */
+
+	List	   *fdw_private;	/* FDW-private information from planner */
+
+	/* 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? */
+	bool		extparams_done; /* have we converted PARAM_EXTERN params? */
+	int			numParams;		/* number of parameters passed to query */
+	Oid		   *param_types;	/* array of types of query parameters */
+	const char **param_values;	/* array of values of query parameters */
+
+	/* for storing result tuples */
+	HeapTuple  *tuples;			/* array of currently-retrieved tuples */
+	int			num_tuples;		/* # of tuples in array */
+	int			next_tuple;		/* index of next one to return */
+
+	/* batch-level state, for optimizing rewinds and avoiding useless fetch */
+	int			fetch_ct_2;		/* Min(# of fetches done, 2) */
+	bool		eof_reached;	/* true if last fetch reached EOF */
+
+	/* working memory contexts */
+	MemoryContext batch_cxt;	/* context holding current batch of tuples */
+	MemoryContext temp_cxt;		/* context for per-tuple temporary data */
+} PgFdwExecutionState;
+
+/*
+ * Workspace for analyzing a foreign table.
+ */
+typedef struct PgFdwAnalyzeState
+{
+	Relation	rel;			/* relcache entry for the foreign table */
+	AttInMetadata *attinmeta;	/* attribute datatype conversion metadata */
+
+	/* collected sample rows */
+	HeapTuple  *rows;			/* array of size targrows */
+	int			targrows;		/* target # of sample rows */
+	int			numrows;		/* # of sample rows collected */
+
+	/* for random sampling */
+	double		samplerows;		/* # of rows fetched */
+	double		rowstoskip;		/* # of rows to skip before next sample */
+	double		rstate;			/* random state */
+
+	/* 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 */
+	AttrNumber	cur_attno;		/* attribute number being processed, or 0 */
+} ConversionLocation;
+
+/*
+ * SQL functions
+ */
+extern Datum postgres_fdw_handler(PG_FUNCTION_ARGS);
+
+PG_FUNCTION_INFO_V1(postgres_fdw_handler);
+
+/*
+ * FDW callback routines
+ */
+static void postgresGetForeignRelSize(PlannerInfo *root,
+						  RelOptInfo *baserel,
+						  Oid foreigntableid);
+static void postgresGetForeignPaths(PlannerInfo *root,
+						RelOptInfo *baserel,
+						Oid foreigntableid);
+static ForeignScan *postgresGetForeignPlan(PlannerInfo *root,
+					   RelOptInfo *baserel,
+					   Oid foreigntableid,
+					   ForeignPath *best_path,
+					   List *tlist,
+					   List *scan_clauses);
+static void postgresExplainForeignScan(ForeignScanState *node,
+						   ExplainState *es);
+static void postgresBeginForeignScan(ForeignScanState *node, int eflags);
+static TupleTableSlot *postgresIterateForeignScan(ForeignScanState *node);
+static void postgresReScanForeignScan(ForeignScanState *node);
+static void postgresEndForeignScan(ForeignScanState *node);
+static bool postgresAnalyzeForeignTable(Relation relation,
+							AcquireSampleRowsFunc *func,
+							BlockNumber *totalpages);
+
+/*
+ * Helper functions
+ */
+static void get_remote_estimate(const char *sql,
+					PGconn *conn,
+					double *rows,
+					int *width,
+					Cost *startup_cost,
+					Cost *total_cost);
+static void create_cursor(ForeignScanState *node);
+static void fetch_more_data(ForeignScanState *node);
+static void close_cursor(PGconn *conn, unsigned int cursor_number);
+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,
+						   MemoryContext temp_context);
+static void conversion_error_callback(void *arg);
+
+
+/*
+ * 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);
+
+	/* Required handler functions. */
+	routine->GetForeignRelSize = postgresGetForeignRelSize;
+	routine->GetForeignPaths = postgresGetForeignPaths;
+	routine->GetForeignPlan = postgresGetForeignPlan;
+	routine->ExplainForeignScan = postgresExplainForeignScan;
+	routine->BeginForeignScan = postgresBeginForeignScan;
+	routine->IterateForeignScan = postgresIterateForeignScan;
+	routine->ReScanForeignScan = postgresReScanForeignScan;
+	routine->EndForeignScan = postgresEndForeignScan;
+
+	/* Optional handler functions. */
+	routine->AnalyzeForeignTable = postgresAnalyzeForeignTable;
+
+	PG_RETURN_POINTER(routine);
+}
+
+/*
+ * postgresGetForeignRelSize
+ *		Estimate # of rows and width of the result of the scan
+ *
+ * Here we estimate number of rows returned by the scan in two steps.  In the
+ * first step, we execute remote EXPLAIN command to obtain the number of rows
+ * returned from remote side.  In the second step, we calculate the selectivity
+ * of the filtering done on local side, and modify first estimate.
+ *
+ * We have to get some catalog objects and generate remote query string here,
+ * so we store such expensive information in FDW private area of RelOptInfo and
+ * pass them to subsequent functions for reuse.
+ */
+static void
+postgresGetForeignRelSize(PlannerInfo *root,
+						  RelOptInfo *baserel,
+						  Oid foreigntableid)
+{
+	bool		use_remote_explain = false;
+	ListCell   *lc;
+	PgFdwRelationInfo *fpinfo;
+	StringInfo	sql;
+	ForeignTable *table;
+	ForeignServer *server;
+	Selectivity sel;
+	double		rows;
+	int			width;
+	Cost		startup_cost;
+	Cost		total_cost;
+	List	   *remote_conds;
+	List	   *param_conds;
+	List	   *local_conds;
+	List	   *param_numbers;
+
+	/*
+	 * We use PgFdwRelationInfo to pass various information to subsequent
+	 * functions.
+	 */
+	fpinfo = palloc0(sizeof(PgFdwRelationInfo));
+	initStringInfo(&fpinfo->sql);
+	sql = &fpinfo->sql;
+
+	/*
+	 * Determine whether we use remote estimate or not.  Note that per-table
+	 * setting overrides per-server setting.
+	 */
+	table = GetForeignTable(foreigntableid);
+	server = GetForeignServer(table->serverid);
+	foreach(lc, server->options)
+	{
+		DefElem    *def = (DefElem *) lfirst(lc);
+
+		if (strcmp(def->defname, "use_remote_explain") == 0)
+		{
+			use_remote_explain = defGetBoolean(def);
+			break;
+		}
+	}
+	foreach(lc, table->options)
+	{
+		DefElem    *def = (DefElem *) lfirst(lc);
+
+		if (strcmp(def->defname, "use_remote_explain") == 0)
+		{
+			use_remote_explain = defGetBoolean(def);
+			break;
+		}
+	}
+
+	/*
+	 * Construct remote query which consists of SELECT, FROM, and WHERE
+	 * clauses.  Conditions which contain any Param node are excluded because
+	 * placeholder can't be used in EXPLAIN statement.  Such conditions are
+	 * appended later.
+	 */
+	classifyConditions(root, baserel, &remote_conds, &param_conds,
+					   &local_conds, &param_numbers);
+	deparseSimpleSql(sql, root, baserel, local_conds);
+	if (list_length(remote_conds) > 0)
+		appendWhereClause(sql, true, remote_conds, root);
+
+	/*
+	 * If the table or the server is configured to use remote EXPLAIN, connect
+	 * to the foreign server and execute EXPLAIN with the quals that don't
+	 * contain any Param nodes.  Otherwise, estimate rows using whatever
+	 * statistics we have locally, in a way similar to ordinary tables.
+	 */
+	if (use_remote_explain)
+	{
+		RangeTblEntry *rte;
+		Oid			userid;
+		UserMapping *user;
+		PGconn	   *conn;
+
+		/*
+		 * Identify which user to do the remote access as.	This should match
+		 * what ExecCheckRTEPerms() does.  If we fail due to lack of
+		 * permissions, the query would have failed at runtime anyway.
+		 */
+		rte = planner_rt_fetch(baserel->relid, root);
+		userid = rte->checkAsUser ? rte->checkAsUser : GetUserId();
+
+		user = GetUserMapping(userid, server->serverid);
+		conn = GetConnection(server, user);
+		get_remote_estimate(sql->data, conn, &rows, &width,
+							&startup_cost, &total_cost);
+		ReleaseConnection(conn);
+
+		/*
+		 * Estimate selectivity of conditions which were not used in remote
+		 * EXPLAIN by calling clauselist_selectivity().  The best we can do
+		 * for these conditions is to estimate selectivity on the basis of
+		 * local statistics.
+		 */
+		sel = clauselist_selectivity(root, param_conds,
+									 baserel->relid, JOIN_INNER, NULL);
+		sel *= clauselist_selectivity(root, local_conds,
+									  baserel->relid, JOIN_INNER, NULL);
+
+		/* Report estimated numbers to planner. */
+		baserel->rows = clamp_row_est(rows * sel);
+		baserel->width = width;
+	}
+	else
+	{
+		/*
+		 * Estimate rows from the result of the last ANALYZE, using all
+		 * conditions specified in original query.
+		 *
+		 * If the foreign table has never been ANALYZEd, it will have relpages
+		 * and reltuples equal to zero, which most likely has nothing to do
+		 * with reality.  We can't do a whole lot about that if we're not
+		 * allowed to consult the remote server, but we can use a hack similar
+		 * to plancat.c's treatment of empty relations: use a minimum size
+		 * estimate of 10 pages, and divide by the column-datatype-based width
+		 * estimate to get the corresponding number of tuples.
+		 */
+		if (baserel->tuples <= 0)
+			baserel->tuples =
+				(10 * BLCKSZ) / (baserel->width + sizeof(HeapTupleHeaderData));
+
+		set_baserel_size_estimates(root, baserel);
+
+		/*
+		 * XXX need to do something here to calculate sane startup and total
+		 * cost estimates ... for the moment, we do this:
+		 */
+		startup_cost = 0;
+		total_cost = baserel->rows * cpu_tuple_cost;
+	}
+
+	/*
+	 * Finish deparsing remote query by adding conditions which were unusable
+	 * in remote EXPLAIN since they contain Param nodes.
+	 */
+	if (list_length(param_conds) > 0)
+		appendWhereClause(sql, !(list_length(remote_conds) > 0), param_conds,
+						  root);
+
+	/*
+	 * Store obtained information into FDW-private area of RelOptInfo so it's
+	 * available to subsequent functions.
+	 */
+	fpinfo->startup_cost = startup_cost;
+	fpinfo->total_cost = total_cost;
+	fpinfo->remote_conds = remote_conds;
+	fpinfo->param_conds = param_conds;
+	fpinfo->local_conds = local_conds;
+	fpinfo->param_numbers = param_numbers;
+	fpinfo->table = table;
+	fpinfo->server = server;
+	baserel->fdw_private = (void *) fpinfo;
+}
+
+/*
+ * postgresGetForeignPaths
+ *		Create possible scan paths for a scan on the foreign table
+ */
+static void
+postgresGetForeignPaths(PlannerInfo *root,
+						RelOptInfo *baserel,
+						Oid foreigntableid)
+{
+	PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) baserel->fdw_private;
+	ForeignPath *path;
+	ListCell   *lc;
+	double		fdw_startup_cost = DEFAULT_FDW_STARTUP_COST;
+	double		fdw_tuple_cost = DEFAULT_FDW_TUPLE_COST;
+	Cost		startup_cost;
+	Cost		total_cost;
+	List	   *fdw_private;
+
+	/*
+	 * Check for user override of fdw_startup_cost, fdw_tuple_cost values
+	 */
+	foreach(lc, fpinfo->server->options)
+	{
+		DefElem    *d = (DefElem *) lfirst(lc);
+
+		if (strcmp(d->defname, "fdw_startup_cost") == 0)
+			fdw_startup_cost = strtod(defGetString(d), NULL);
+		else if (strcmp(d->defname, "fdw_tuple_cost") == 0)
+			fdw_tuple_cost = strtod(defGetString(d), NULL);
+	}
+
+	/*
+	 * We have cost values which are estimated on remote side, so adjust them
+	 * for better estimate which respect various stuffs to complete the scan,
+	 * such as sending query, transferring result, and local filtering.
+	 */
+	startup_cost = fpinfo->startup_cost;
+	total_cost = fpinfo->total_cost;
+
+	/*----------
+	 * Adjust costs with factors of the corresponding foreign server:
+	 *	 - add cost to establish connection to both startup and total
+	 *	 - add cost to manipulate on remote, and transfer result to total
+	 *	 - add cost to manipulate tuples on local side to total
+	 *----------
+	 */
+	startup_cost += fdw_startup_cost;
+	total_cost += fdw_startup_cost;
+	total_cost += fdw_tuple_cost * baserel->rows;
+	total_cost += cpu_tuple_cost * baserel->rows;
+
+	/*
+	 * Build the fdw_private list that will be available to the executor.
+	 * Items in the list must match enum FdwPrivateIndex, above.
+	 */
+	fdw_private = list_make2(makeString(fpinfo->sql.data),
+							 fpinfo->param_numbers);
+
+	/*
+	 * Create simplest ForeignScan path node and add it to baserel.  This path
+	 * corresponds to SeqScan path of regular tables (though depending on what
+	 * baserestrict conditions we were able to send to remote, there might
+	 * actually be an indexscan happening there).
+	 */
+	path = create_foreignscan_path(root, baserel,
+								   baserel->rows,
+								   startup_cost,
+								   total_cost,
+								   NIL, /* no pathkeys */
+								   NULL,		/* no outer rel either */
+								   fdw_private);
+	add_path(baserel, (Path *) path);
+
+	/*
+	 * XXX We can consider sorted path or parameterized path here if we know
+	 * that foreign table is indexed on remote end.  For this purpose, we
+	 * might have to support FOREIGN INDEX to represent possible sets of sort
+	 * keys and/or filtering.  Or we could just try some join conditions and
+	 * see if remote side estimates using them as markedly cheaper.  Note that
+	 * executor functions need work to support internal Params before we can
+	 * try generating any parameterized paths, though.
+	 */
+}
+
+/*
+ * postgresGetForeignPlan
+ *		Create ForeignScan plan node which implements selected best path
+ */
+static ForeignScan *
+postgresGetForeignPlan(PlannerInfo *root,
+					   RelOptInfo *baserel,
+					   Oid foreigntableid,
+					   ForeignPath *best_path,
+					   List *tlist,
+					   List *scan_clauses)
+{
+	PgFdwRelationInfo *fpinfo = (PgFdwRelationInfo *) baserel->fdw_private;
+	Index		scan_relid = baserel->relid;
+	List	   *fdw_private = best_path->fdw_private;
+	List	   *remote_exprs = NIL;
+	List	   *local_exprs = NIL;
+	ListCell   *lc;
+
+	/*
+	 * Separate the scan_clauses into those that can be executed remotely and
+	 * those that can't.  For now, we accept only remote clauses that were
+	 * previously determined to be safe by classifyClauses (so, only
+	 * baserestrictinfo clauses can be used that way).
+	 *
+	 * This code must match "extract_actual_clauses(scan_clauses, false)"
+	 * except for the additional decision about remote versus local execution.
+	 */
+	foreach(lc, scan_clauses)
+	{
+		RestrictInfo *rinfo = (RestrictInfo *) lfirst(lc);
+
+		Assert(IsA(rinfo, RestrictInfo));
+
+		/* Ignore any pseudoconstants, they're dealt with elsewhere */
+		if (rinfo->pseudoconstant)
+			continue;
+
+		/* Either simple or parameterized remote clauses are OK now */
+		if (list_member_ptr(fpinfo->remote_conds, rinfo) ||
+			list_member_ptr(fpinfo->param_conds, rinfo))
+			remote_exprs = lappend(remote_exprs, rinfo->clause);
+		else
+			local_exprs = lappend(local_exprs, rinfo->clause);
+	}
+
+	/*
+	 * Create the ForeignScan node from target list, local filtering
+	 * expressions, remote filtering expressions, and FDW private information.
+	 *
+	 * Note that the remote_exprs 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.
+	 *
+	 * XXX Currently, the remote_exprs aren't actually used at runtime, so we
+	 * don't need to store them at all.  But we'll keep this behavior for a
+	 * little while for debugging reasons.
+	 */
+	return make_foreignscan(tlist,
+							local_exprs,
+							scan_relid,
+							remote_exprs,
+							fdw_private);
+}
+
+/*
+ * postgresExplainForeignScan
+ *		Produce extra output for EXPLAIN
+ */
+static void
+postgresExplainForeignScan(ForeignScanState *node, ExplainState *es)
+{
+	List	   *fdw_private;
+	char	   *sql;
+
+	if (es->verbose)
+	{
+		fdw_private = ((ForeignScan *) node->ss.ps.plan)->fdw_private;
+		sql = strVal(list_nth(fdw_private, FdwPrivateSelectSql));
+		ExplainPropertyText("Remote SQL", sql, es);
+	}
+}
+
+/*
+ * 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;
+	PgFdwExecutionState *festate;
+	RangeTblEntry *rte;
+	Oid			userid;
+	ForeignTable *table;
+	ForeignServer *server;
+	UserMapping *user;
+	List	   *param_numbers;
+	int			numParams;
+	int			i;
+
+	/*
+	 * 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.
+	 */
+	festate = (PgFdwExecutionState *) palloc0(sizeof(PgFdwExecutionState));
+	node->fdw_state = (void *) festate;
+
+	/*
+	 * Identify which user to do the remote access as.	This should match what
+	 * ExecCheckRTEPerms() does.
+	 */
+	rte = rt_fetch(fsplan->scan.scanrelid, estate->es_range_table);
+	userid = rte->checkAsUser ? rte->checkAsUser : GetUserId();
+
+	/* Get info about foreign table. */
+	festate->rel = node->ss.ss_currentRelation;
+	table = GetForeignTable(RelationGetRelid(festate->rel));
+	server = GetForeignServer(table->serverid);
+	user = GetUserMapping(userid, server->serverid);
+
+	/*
+	 * Get connection to the foreign server.  Connection manager will
+	 * establish new connection if necessary.
+	 */
+	festate->conn = GetConnection(server, user);
+
+	/* Assign a unique ID for my cursor */
+	festate->cursor_number = GetCursorNumber(festate->conn);
+	festate->cursor_exists = false;
+
+	/* Get private info created by planner functions. */
+	festate->fdw_private = fsplan->fdw_private;
+
+	/* Create contexts for batches of tuples and per-tuple temp workspace. */
+	festate->batch_cxt = AllocSetContextCreate(estate->es_query_cxt,
+											   "postgres_fdw tuple data",
+											   ALLOCSET_DEFAULT_MINSIZE,
+											   ALLOCSET_DEFAULT_INITSIZE,
+											   ALLOCSET_DEFAULT_MAXSIZE);
+	festate->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 data conversion. */
+	festate->attinmeta = TupleDescGetAttInMetadata(RelationGetDescr(festate->rel));
+
+	/*
+	 * Allocate buffer for query parameters, if the remote conditions use any.
+	 *
+	 * We use a parameter slot for each PARAM_EXTERN parameter, even though
+	 * not all of them may get sent to the remote server.  This allows us to
+	 * refer to Params by their original number rather than remapping, and it
+	 * doesn't cost much.  Slots that are not actually used get filled with
+	 * null values that are arbitrarily marked as being of type int4.
+	 */
+	param_numbers = (List *)
+		list_nth(festate->fdw_private, FdwPrivateExternParamIds);
+	if (param_numbers != NIL)
+	{
+		ParamListInfo params = estate->es_param_list_info;
+
+		numParams = params ? params->numParams : 0;
+	}
+	else
+		numParams = 0;
+	festate->numParams = numParams;
+	if (numParams > 0)
+	{
+		/* we initially fill all slots with value = NULL, type = int4 */
+		festate->param_types = (Oid *) palloc(numParams * sizeof(Oid));
+		festate->param_values = (const char **) palloc0(numParams * sizeof(char *));
+		for (i = 0; i < numParams; i++)
+			festate->param_types[i] = INT4OID;
+	}
+	else
+	{
+		festate->param_types = NULL;
+		festate->param_values = NULL;
+	}
+	festate->extparams_done = false;
+}
+
+/*
+ * postgresIterateForeignScan
+ *		Retrieve next row from the result set, or clear tuple slot to indicate
+ *		EOF.
+ */
+static TupleTableSlot *
+postgresIterateForeignScan(ForeignScanState *node)
+{
+	PgFdwExecutionState *festate = (PgFdwExecutionState *) node->fdw_state;
+	TupleTableSlot *slot = node->ss.ss_ScanTupleSlot;
+
+	/*
+	 * If this is the first call after Begin or ReScan, we need to create the
+	 * cursor on the remote side.
+	 */
+	if (!festate->cursor_exists)
+		create_cursor(node);
+
+	/*
+	 * Get some more tuples, if we've run out.
+	 */
+	if (festate->next_tuple >= festate->num_tuples)
+	{
+		/* No point in another fetch if we already detected EOF, though. */
+		if (!festate->eof_reached)
+			fetch_more_data(node);
+		/* If we didn't get any tuples, must be end of data. */
+		if (festate->next_tuple >= festate->num_tuples)
+			return ExecClearTuple(slot);
+	}
+
+	/*
+	 * Return the next tuple.
+	 */
+	ExecStoreTuple(festate->tuples[festate->next_tuple++],
+				   slot,
+				   InvalidBuffer,
+				   false);
+
+	return slot;
+}
+
+/*
+ * postgresReScanForeignScan
+ *		Restart the scan.
+ */
+static void
+postgresReScanForeignScan(ForeignScanState *node)
+{
+	PgFdwExecutionState *festate = (PgFdwExecutionState *) node->fdw_state;
+	char		sql[64];
+	PGresult   *res;
+
+	/*
+	 * Note: we assume that PARAM_EXTERN params don't change over the life of
+	 * the query, so no need to reset extparams_done.
+	 */
+
+	/* If we haven't created the cursor yet, nothing to do. */
+	if (!festate->cursor_exists)
+		return;
+
+	/*
+	 * If any internal parameters affecting this node have changed, we'd
+	 * better destroy and recreate the cursor.	Otherwise, rewinding it should
+	 * be good enough.	If we've only fetched zero or one batch, we needn't
+	 * even rewind the cursor, just rescan what we have.
+	 */
+	if (node->ss.ps.chgParam != NULL)
+	{
+		festate->cursor_exists = false;
+		snprintf(sql, sizeof(sql), "CLOSE c%u",
+				 festate->cursor_number);
+	}
+	else if (festate->fetch_ct_2 > 1)
+	{
+		snprintf(sql, sizeof(sql), "MOVE BACKWARD ALL IN c%u",
+				 festate->cursor_number);
+	}
+	else
+	{
+		/* Easy: just rescan what we already have in memory, if anything */
+		festate->next_tuple = 0;
+		return;
+	}
+
+	/*
+	 * We don't use a PG_TRY block here, so be careful not to throw error
+	 * without releasing the PGresult.
+	 */
+	res = PQexec(festate->conn, sql);
+	if (PQresultStatus(res) != PGRES_COMMAND_OK)
+		pgfdw_report_error(ERROR, res, true, sql);
+	PQclear(res);
+
+	/* Now force a fresh FETCH. */
+	festate->tuples = NULL;
+	festate->num_tuples = 0;
+	festate->next_tuple = 0;
+	festate->fetch_ct_2 = 0;
+	festate->eof_reached = false;
+}
+
+/*
+ * postgresEndForeignScan
+ *		Finish scanning foreign table and dispose objects used for this scan
+ */
+static void
+postgresEndForeignScan(ForeignScanState *node)
+{
+	PgFdwExecutionState *festate = (PgFdwExecutionState *) node->fdw_state;
+
+	/* if festate is NULL, we are in EXPLAIN; nothing to do */
+	if (festate == NULL)
+		return;
+
+	/* Close the cursor if open, to prevent accumulation of cursors */
+	if (festate->cursor_exists)
+		close_cursor(festate->conn, festate->cursor_number);
+
+	/* Release remote connection */
+	ReleaseConnection(festate->conn);
+	festate->conn = NULL;
+
+	/* MemoryContexts will be deleted automatically. */
+}
+
+/*
+ * Estimate costs of executing given SQL statement.
+ */
+static void
+get_remote_estimate(const char *sql, PGconn *conn,
+					double *rows, int *width,
+					Cost *startup_cost, Cost *total_cost)
+{
+	PGresult   *volatile res = NULL;
+
+	/* PGresult must be released before leaving this function. */
+	PG_TRY();
+	{
+		StringInfoData buf;
+		char	   *line;
+		char	   *p;
+		int			n;
+
+		/*
+		 * Execute EXPLAIN remotely on given SQL statement.
+		 */
+		initStringInfo(&buf);
+		appendStringInfo(&buf, "EXPLAIN %s", sql);
+		res = PQexec(conn, buf.data);
+		if (PQresultStatus(res) != PGRES_TUPLES_OK)
+			pgfdw_report_error(ERROR, res, false, buf.data);
+
+		/*
+		 * Extract cost numbers for topmost plan node.	Note we search for a
+		 * left paren from the end of the line to avoid being confused by
+		 * other uses of parentheses.
+		 */
+		line = PQgetvalue(res, 0, 0);
+		p = strrchr(line, '(');
+		if (p == NULL)
+			elog(ERROR, "could not interpret EXPLAIN output: \"%s\"", line);
+		n = sscanf(p, "(cost=%lf..%lf rows=%lf width=%d)",
+				   startup_cost, total_cost, rows, width);
+		if (n != 4)
+			elog(ERROR, "could not interpret EXPLAIN output: \"%s\"", line);
+
+		PQclear(res);
+		res = NULL;
+	}
+	PG_CATCH();
+	{
+		if (res)
+			PQclear(res);
+		PG_RE_THROW();
+	}
+	PG_END_TRY();
+}
+
+/*
+ * Create cursor for node's query with current parameter values.
+ */
+static void
+create_cursor(ForeignScanState *node)
+{
+	PgFdwExecutionState *festate = (PgFdwExecutionState *) node->fdw_state;
+	int			numParams = festate->numParams;
+	Oid		   *types = festate->param_types;
+	const char **values = festate->param_values;
+	PGconn	   *conn = festate->conn;
+	char	   *sql;
+	StringInfoData buf;
+	PGresult   *res;
+
+	/*
+	 * Construct array of external parameter values in text format.  Since
+	 * there might be random unconvertible stuff in the ParamExternData array,
+	 * take care to convert only values we actually need.
+	 *
+	 * Note that we leak the memory for the value strings until end of query;
+	 * this doesn't seem like a big problem, and in any case we might need to
+	 * recreate the cursor after a rescan, so we could need to re-use the
+	 * values anyway.
+	 */
+	if (numParams > 0 && !festate->extparams_done)
+	{
+		ParamListInfo params = node->ss.ps.state->es_param_list_info;
+		List	   *param_numbers;
+		ListCell   *lc;
+
+		param_numbers = (List *)
+			list_nth(festate->fdw_private, FdwPrivateExternParamIds);
+		foreach(lc, param_numbers)
+		{
+			int			paramno = lfirst_int(lc);
+			ParamExternData *prm = &params->params[paramno - 1];
+
+			/* give hook a chance in case parameter is dynamic */
+			if (!OidIsValid(prm->ptype) && params->paramFetch != NULL)
+				params->paramFetch(params, paramno);
+
+			/*
+			 * Get string representation of each parameter value by invoking
+			 * type-specific output function, unless the value is null.
+			 */
+			types[paramno - 1] = prm->ptype;
+			if (prm->isnull)
+				values[paramno - 1] = NULL;
+			else
+			{
+				Oid			out_func;
+				bool		isvarlena;
+
+				getTypeOutputInfo(prm->ptype, &out_func, &isvarlena);
+				values[paramno - 1] = OidOutputFunctionCall(out_func,
+															prm->value);
+			}
+		}
+		festate->extparams_done = true;
+	}
+
+	/* Construct the DECLARE CURSOR command */
+	sql = strVal(list_nth(festate->fdw_private, FdwPrivateSelectSql));
+	initStringInfo(&buf);
+	appendStringInfo(&buf, "DECLARE c%u CURSOR FOR\n%s",
+					 festate->cursor_number, sql);
+
+	/*
+	 * We don't use a PG_TRY block here, so be careful not to throw error
+	 * without releasing the PGresult.
+	 */
+	res = PQexecParams(conn, buf.data, numParams, types, values,
+					   NULL, NULL, 0);
+	if (PQresultStatus(res) != PGRES_COMMAND_OK)
+		pgfdw_report_error(ERROR, res, true, sql);
+	PQclear(res);
+
+	/* Mark the cursor as created, and show no tuples have been retrieved */
+	festate->cursor_exists = true;
+	festate->tuples = NULL;
+	festate->num_tuples = 0;
+	festate->next_tuple = 0;
+	festate->fetch_ct_2 = 0;
+	festate->eof_reached = false;
+
+	/* Clean up */
+	pfree(buf.data);
+}
+
+/*
+ * Fetch some more rows from the node's cursor.
+ */
+static void
+fetch_more_data(ForeignScanState *node)
+{
+	PgFdwExecutionState *festate = (PgFdwExecutionState *) node->fdw_state;
+	PGresult   *volatile res = NULL;
+	MemoryContext oldcontext;
+
+	/*
+	 * We'll store the tuples in the batch_cxt.  First, flush the previous
+	 * batch.
+	 */
+	festate->tuples = NULL;
+	MemoryContextReset(festate->batch_cxt);
+	oldcontext = MemoryContextSwitchTo(festate->batch_cxt);
+
+	/* PGresult must be released before leaving this function. */
+	PG_TRY();
+	{
+		PGconn	   *conn = festate->conn;
+		char		sql[64];
+		int			fetch_size;
+		int			numrows;
+		int			i;
+
+		/* The fetch size is arbitrary, but shouldn't be enormous. */
+		fetch_size = 100;
+
+		snprintf(sql, sizeof(sql), "FETCH %d FROM c%u",
+				 fetch_size, festate->cursor_number);
+
+		res = PQexec(conn, sql);
+		/* On error, report the original query, not the FETCH. */
+		if (PQresultStatus(res) != PGRES_TUPLES_OK)
+			pgfdw_report_error(ERROR, res, false,
+							   strVal(list_nth(festate->fdw_private,
+											   FdwPrivateSelectSql)));
+
+		/* Convert the data into HeapTuples */
+		numrows = PQntuples(res);
+		festate->tuples = (HeapTuple *) palloc0(numrows * sizeof(HeapTuple));
+		festate->num_tuples = numrows;
+		festate->next_tuple = 0;
+
+		for (i = 0; i < numrows; i++)
+		{
+			festate->tuples[i] =
+				make_tuple_from_result_row(res, i,
+										   festate->rel,
+										   festate->attinmeta,
+										   festate->temp_cxt);
+		}
+
+		/* Update fetch_ct_2 */
+		if (festate->fetch_ct_2 < 2)
+			festate->fetch_ct_2++;
+
+		/* Must be EOF if we didn't get as many tuples as we asked for. */
+		festate->eof_reached = (numrows < fetch_size);
+
+		PQclear(res);
+		res = NULL;
+	}
+	PG_CATCH();
+	{
+		if (res)
+			PQclear(res);
+		PG_RE_THROW();
+	}
+	PG_END_TRY();
+
+	MemoryContextSwitchTo(oldcontext);
+}
+
+/*
+ * Utility routine to close a cursor.
+ */
+static void
+close_cursor(PGconn *conn, unsigned int cursor_number)
+{
+	char		sql[64];
+	PGresult   *res;
+
+	snprintf(sql, sizeof(sql), "CLOSE c%u", cursor_number);
+
+	/*
+	 * We don't use a PG_TRY block here, so be careful not to throw error
+	 * without releasing the PGresult.
+	 */
+	res = PQexec(conn, sql);
+	if (PQresultStatus(res) != PGRES_COMMAND_OK)
+		pgfdw_report_error(ERROR, res, true, sql);
+	PQclear(res);
+}
+
+/*
+ * postgresAnalyzeForeignTable
+ *		Test whether analyzing this foreign table is supported
+ */
+static bool
+postgresAnalyzeForeignTable(Relation relation,
+							AcquireSampleRowsFunc *func,
+							BlockNumber *totalpages)
+{
+	*totalpages = 0;			/* XXX this is probably a bad idea */
+	*func = postgresAcquireSampleRowsFunc;
+
+	return true;
+}
+
+/*
+ * Acquire a random sample of rows from foreign table managed by postgres_fdw.
+ *
+ * We fetch the whole table from the remote side and pick out some sample rows.
+ *
+ * Selected rows are returned in the caller-allocated array rows[],
+ * which must have at least targrows entries.
+ * The actual number of rows selected is returned as the function result.
+ * We also count the total number of rows in the table and return it into
+ * *totalrows.	Note that *totaldeadrows is always set to 0.
+ *
+ * Note that the returned list of rows is not always in order by physical
+ * position in the table.  Therefore, correlation estimates derived later
+ * may be meaningless, but it's OK because we don't use the estimates
+ * currently (the planner only pays attention to correlation for indexscans).
+ */
+static int
+postgresAcquireSampleRowsFunc(Relation relation, int elevel,
+							  HeapTuple *rows, int targrows,
+							  double *totalrows,
+							  double *totaldeadrows)
+{
+	PgFdwAnalyzeState astate;
+	ForeignTable *table;
+	ForeignServer *server;
+	UserMapping *user;
+	PGconn	   *conn;
+	unsigned int cursor_number;
+	StringInfoData sql;
+	PGresult   *volatile res = NULL;
+
+	/* Initialize workspace state */
+	astate.rel = relation;
+	astate.attinmeta = TupleDescGetAttInMetadata(RelationGetDescr(relation));
+
+	astate.rows = rows;
+	astate.targrows = targrows;
+	astate.numrows = 0;
+	astate.samplerows = 0;
+	astate.rowstoskip = -1;		/* -1 means not set yet */
+	astate.rstate = anl_init_selection_state(targrows);
+
+	/* Remember ANALYZE context, and create a per-tuple temp context */
+	astate.anl_cxt = CurrentMemoryContext;
+	astate.temp_cxt = AllocSetContextCreate(CurrentMemoryContext,
+											"postgres_fdw temporary data",
+											ALLOCSET_SMALL_MINSIZE,
+											ALLOCSET_SMALL_INITSIZE,
+											ALLOCSET_SMALL_MAXSIZE);
+
+	/*
+	 * Get the connection to use.  We do the remote access as the table's
+	 * owner, even if the ANALYZE was started by some other user.
+	 */
+	table = GetForeignTable(RelationGetRelid(relation));
+	server = GetForeignServer(table->serverid);
+	user = GetUserMapping(relation->rd_rel->relowner, server->serverid);
+	conn = GetConnection(server, user);
+
+	/*
+	 * Construct cursor that retrieves whole rows from remote.
+	 */
+	cursor_number = GetCursorNumber(conn);
+	initStringInfo(&sql);
+	appendStringInfo(&sql, "DECLARE c%u CURSOR FOR ", cursor_number);
+	deparseAnalyzeSql(&sql, relation);
+
+	/* In what follows, do not risk leaking any PGresults. */
+	PG_TRY();
+	{
+		res = PQexec(conn, sql.data);
+		if (PQresultStatus(res) != PGRES_COMMAND_OK)
+			pgfdw_report_error(ERROR, res, false, sql.data);
+		PQclear(res);
+		res = NULL;
+
+		/* Retrieve and process rows a batch at a time. */
+		for (;;)
+		{
+			char		fetch_sql[64];
+			int			fetch_size;
+			int			numrows;
+			int			i;
+
+			/* Allow users to cancel long query */
+			CHECK_FOR_INTERRUPTS();
+
+			/*
+			 * XXX possible future improvement: if rowstoskip is large, we
+			 * could issue a MOVE rather than physically fetching the rows,
+			 * then just adjust rowstoskip and samplerows appropriately.
+			 */
+
+			/* The fetch size is arbitrary, but shouldn't be enormous. */
+			fetch_size = 100;
+
+			/* Fetch some rows */
+			snprintf(fetch_sql, sizeof(fetch_sql), "FETCH %d FROM c%u",
+					 fetch_size, cursor_number);
+
+			res = PQexec(conn, fetch_sql);
+			/* On error, report the original query, not the FETCH. */
+			if (PQresultStatus(res) != PGRES_TUPLES_OK)
+				pgfdw_report_error(ERROR, res, false, sql.data);
+
+			/* Process whatever we got. */
+			numrows = PQntuples(res);
+			for (i = 0; i < numrows; i++)
+				analyze_row_processor(res, i, &astate);
+
+			PQclear(res);
+			res = NULL;
+
+			/* Must be EOF if we didn't get all the rows requested. */
+			if (numrows < fetch_size)
+				break;
+		}
+
+		/* Close the cursor, just to be tidy. */
+		close_cursor(conn, cursor_number);
+	}
+	PG_CATCH();
+	{
+		if (res)
+			PQclear(res);
+		PG_RE_THROW();
+	}
+	PG_END_TRY();
+
+	ReleaseConnection(conn);
+
+	/* We assume that we have no dead tuple. */
+	*totaldeadrows = 0.0;
+
+	/* We've retrieved all living tuples from foreign server. */
+	*totalrows = astate.samplerows;
+
+	/*
+	 * Emit some interesting relation info
+	 */
+	ereport(elevel,
+			(errmsg("\"%s\": table contains %.0f rows, %d rows in sample",
+					RelationGetRelationName(relation),
+					astate.samplerows, astate.numrows)));
+
+	return astate.numrows;
+}
+
+/*
+ * Collect sample rows from the result of query.
+ *	 - Use all tuples in sample until target # of samples are collected.
+ *	 - Subsequently, replace already-sampled tuples randomly.
+ */
+static void
+analyze_row_processor(PGresult *res, int row, PgFdwAnalyzeState *astate)
+{
+	int			targrows = astate->targrows;
+	int			pos;			/* array index to store tuple in */
+	MemoryContext oldcontext;
+
+	/* Always increment sample row counter. */
+	astate->samplerows += 1;
+
+	/*
+	 * Determine the slot where this sample row should be stored.  Set pos to
+	 * negative value to indicate the row should be skipped.
+	 */
+	if (astate->numrows < targrows)
+	{
+		/* First targrows rows are always included into the sample */
+		pos = astate->numrows++;
+	}
+	else
+	{
+		/*
+		 * Now we start replacing tuples in the sample until we reach the end
+		 * of the relation.  Same algorithm as in acquire_sample_rows in
+		 * analyze.c; see Jeff Vitter's paper.
+		 */
+		if (astate->rowstoskip < 0)
+			astate->rowstoskip = anl_get_next_S(astate->samplerows, targrows,
+												&astate->rstate);
+
+		if (astate->rowstoskip <= 0)
+		{
+			/* Choose a random reservoir element to replace. */
+			pos = (int) (targrows * anl_random_fract());
+			Assert(pos >= 0 && pos < targrows);
+			heap_freetuple(astate->rows[pos]);
+		}
+		else
+		{
+			/* Skip this tuple. */
+			pos = -1;
+		}
+
+		astate->rowstoskip -= 1;
+	}
+
+	if (pos >= 0)
+	{
+		/*
+		 * 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->temp_cxt);
+
+		MemoryContextSwitchTo(oldcontext);
+	}
+}
+
+/*
+ * 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 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,
+						   MemoryContext temp_context)
+{
+	HeapTuple	tuple;
+	TupleDesc	tupdesc = RelationGetDescr(rel);
+	Form_pg_attribute *attrs = tupdesc->attrs;
+	Datum	   *values;
+	bool	   *nulls;
+	ConversionLocation errpos;
+	ErrorContextCallback errcallback;
+	MemoryContext oldcontext;
+	int			i;
+	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);
+
+	values = (Datum *) palloc(tupdesc->natts * sizeof(Datum));
+	nulls = (bool *) palloc(tupdesc->natts * sizeof(bool));
+
+	/*
+	 * Set up and install callback to report where conversion error occurs.
+	 */
+	errpos.rel = rel;
+	errpos.cur_attno = 0;
+	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.
+	 * We assume dropped columns are not represented in the PGresult.
+	 */
+	for (i = 0, j = 0; i < tupdesc->natts; i++)
+	{
+		char	   *valstr;
+
+		/* skip dropped columns. */
+		if (attrs[i]->attisdropped)
+		{
+			values[i] = (Datum) 0;
+			nulls[i] = true;
+			continue;
+		}
+
+		/* convert value to internal representation */
+		if (PQgetisnull(res, row, j))
+		{
+			valstr = NULL;
+			nulls[i] = true;
+		}
+		else
+		{
+			valstr = PQgetvalue(res, row, j);
+			nulls[i] = false;
+		}
+
+		/* Note: apply the input function even to nulls, to support domains */
+		errpos.cur_attno = i + 1;
+		values[i] = InputFunctionCall(&attinmeta->attinfuncs[i],
+									  valstr,
+									  attinmeta->attioparams[i],
+									  attinmeta->atttypmods[i]);
+		errpos.cur_attno = 0;
+
+		j++;
+	}
+
+	/* Uninstall error context callback. */
+	error_context_stack = errcallback.previous;
+
+	/* check result and tuple descriptor have the same number of columns */
+	if (j != PQnfields(res))
+		elog(ERROR, "remote query result does not match the foreign table");
+
+	/*
+	 * Build the result tuple in caller's memory context.
+	 */
+	MemoryContextSwitchTo(oldcontext);
+
+	tuple = heap_form_tuple(tupdesc, values, nulls);
+
+	/* Clean up */
+	MemoryContextReset(temp_context);
+
+	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)
+{
+	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));
+}
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
new file mode 100644
index 0000000000000000000000000000000000000000..f9ed490752b0a2d6b4a60debdd748f4724052194
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw.control
@@ -0,0 +1,5 @@
+# postgres_fdw extension
+comment = 'foreign-data wrapper for remote PostgreSQL servers'
+default_version = '1.0'
+module_pathname = '$libdir/postgres_fdw'
+relocatable = true
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
new file mode 100644
index 0000000000000000000000000000000000000000..52d1d49b25e2a5268d4cdafc8aaebf150a5b29a3
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -0,0 +1,52 @@
+/*-------------------------------------------------------------------------
+ *
+ * postgres_fdw.h
+ *		  Foreign-data wrapper for remote PostgreSQL servers
+ *
+ * Portions Copyright (c) 2012-2013, PostgreSQL Global Development Group
+ *
+ * IDENTIFICATION
+ *		  contrib/postgres_fdw/postgres_fdw.h
+ *
+ *-------------------------------------------------------------------------
+ */
+#ifndef POSTGRES_FDW_H
+#define POSTGRES_FDW_H
+
+#include "foreign/foreign.h"
+#include "lib/stringinfo.h"
+#include "nodes/relation.h"
+#include "utils/rel.h"
+
+#include "libpq-fe.h"
+
+/* in connection.c */
+extern PGconn *GetConnection(ForeignServer *server, UserMapping *user);
+extern void ReleaseConnection(PGconn *conn);
+extern unsigned int GetCursorNumber(PGconn *conn);
+extern void pgfdw_report_error(int elevel, PGresult *res, bool clear,
+				   const char *sql);
+
+/* in option.c */
+extern int ExtractConnectionOptions(List *defelems,
+						 const char **keywords,
+						 const char **values);
+
+/* in deparse.c */
+extern void classifyConditions(PlannerInfo *root,
+				   RelOptInfo *baserel,
+				   List **remote_conds,
+				   List **param_conds,
+				   List **local_conds,
+				   List **param_numbers);
+extern void deparseSimpleSql(StringInfo buf,
+				 PlannerInfo *root,
+				 RelOptInfo *baserel,
+				 List *local_conds);
+extern void appendWhereClause(StringInfo buf,
+				  bool has_where,
+				  List *exprs,
+				  PlannerInfo *root);
+extern void deparseAnalyzeSql(StringInfo buf, Relation rel);
+
+#endif   /* POSTGRES_FDW_H */
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
new file mode 100644
index 0000000000000000000000000000000000000000..0fb2b41117c61328f5fb86735398e164e869d2be
--- /dev/null
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -0,0 +1,272 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+
+CREATE EXTENSION postgres_fdw;
+
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+  OPTIONS (dbname 'contrib_regression');
+
+CREATE USER MAPPING FOR public SERVER testserver1
+	OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+
+-- ===================================================================
+-- 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,
+	c5 timestamp,
+	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)
+);
+
+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;
+
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+	c0 int,
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	c4 timestamptz,
+	c5 timestamp,
+	c6 varchar(10),
+	c7 char(10),
+	c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+
+CREATE FOREIGN TABLE ft2 (
+	c0 int,
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	c4 timestamptz,
+	c5 timestamp,
+	c6 varchar(10),
+	c7 char(10),
+	c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN c0;
+
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl, krbsrvname and gsslib are omitted because they depend on
+-- configure options
+ALTER SERVER testserver1 OPTIONS (
+	use_remote_explain 'false',
+	fdw_startup_cost '123.456',
+	fdw_tuple_cost '0.123',
+	service 'value',
+	connect_timeout 'value',
+	dbname 'value',
+	host 'value',
+	hostaddr 'value',
+	port 'value',
+	--client_encoding 'value',
+	application_name 'value',
+	--fallback_application_name 'value',
+	keepalives 'value',
+	keepalives_idle 'value',
+	keepalives_interval 'value',
+	-- requiressl 'value',
+	sslcompression 'value',
+	sslmode 'value',
+	sslcert 'value',
+	sslkey 'value',
+	sslrootcert 'value',
+	sslcrl 'value'
+	--requirepeer 'value',
+	-- krbsrvname 'value',
+	-- gsslib 'value',
+	--replication 'value'
+);
+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+
+
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote_explain mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_explain 'true');
+
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table, with/without alias
+EXPLAIN (COSTS false) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+-- empty result
+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';
+-- 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;
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+    LEFTARG = int,
+    RIGHTARG = int,
+    PROCEDURE = int4eq,
+    COMMUTATOR = ===,
+    NEGATOR = !==
+);
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 1;         -- Var, OpExpr(b), Const
+EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+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 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 EXTRACT(dow FROM c4) = 6) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st2(10, 20);
+EXECUTE st2(10, 20);
+EXECUTE st1(101, 101);
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND EXTRACT(dow FROM c5) = 6) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st3(10, 20);
+EXECUTE st3(10, 20);
+EXECUTE st3(20, 30);
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st4(1);
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXPLAIN (VERBOSE, COSTS false) EXECUTE st5('foo', 1);
+EXECUTE st5('foo', 1);
+
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+
+-- ===================================================================
+-- used in pl/pgsql function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+	v_c1 int;
+BEGIN
+    SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+    PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+    RETURN v_c1;
+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
+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;
+ERROR OUT;          -- ERROR
+ROLLBACK TO s;
+FETCH c;
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0;  -- ERROR
+ROLLBACK TO s;
+FETCH c;
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+COMMIT;
diff --git a/doc/src/sgml/client-auth.sgml b/doc/src/sgml/client-auth.sgml
index d9d14955f0b6251141e1986e9239928b973ff15e..9fc583ce57407a99f124e1c4de1f545ffb3e2cb8 100644
--- a/doc/src/sgml/client-auth.sgml
+++ b/doc/src/sgml/client-auth.sgml
@@ -1098,7 +1098,7 @@ omicron         bryanh                  guest1
     <replaceable>servicename</> can be set on the server side using the
     <xref linkend="guc-krb-srvname"> configuration parameter, and on the
     client side using the <literal>krbsrvname</> connection parameter. (See
-    also <xref linkend="libpq-connect">.)  The installation default can be
+    also <xref linkend="libpq-paramkeywords">.) The installation default can be
     changed from the default <literal>postgres</literal> at build time using
     <literal>./configure --with-krb-srvnam=</><replaceable>whatever</>.
     In most environments,
diff --git a/doc/src/sgml/contrib.sgml b/doc/src/sgml/contrib.sgml
index 6b13a0abefb9fbebbee2487c6b0bbb96c06e0f24..39e9827fca7b3191cb8528e52418968aee733096 100644
--- a/doc/src/sgml/contrib.sgml
+++ b/doc/src/sgml/contrib.sgml
@@ -132,6 +132,7 @@ CREATE EXTENSION <replaceable>module_name</> FROM unpackaged;
  &pgstatstatements;
  &pgstattuple;
  &pgtrgm;
+ &postgres-fdw;
  &seg;
  &sepgsql;
  &contrib-spi;
diff --git a/doc/src/sgml/dblink.sgml b/doc/src/sgml/dblink.sgml
index 186ab8658653936d1140ccf26ba880ae49bc2336..4bf65c67b1a4fec25ccf8230867d60bd6fc2bd69 100644
--- a/doc/src/sgml/dblink.sgml
+++ b/doc/src/sgml/dblink.sgml
@@ -8,11 +8,16 @@
  </indexterm>
 
  <para>
-  <filename>dblink</> is a module which supports connections to
+  <filename>dblink</> is a module that supports connections to
   other <productname>PostgreSQL</> databases from within a database
   session.
  </para>
 
+ <para>
+  See also <xref linkend="postgres-fdw">, which provides roughly the same
+  functionality using a more modern and standards-compliant infrastructure.
+ </para>
+
  <refentry id="CONTRIB-DBLINK-CONNECT">
   <refmeta>
    <refentrytitle>dblink_connect</refentrytitle>
@@ -47,12 +52,10 @@ dblink_connect(text connname, text connstr) returns text
    <para>
     The connection string may also be the name of an existing foreign
     server.  It is recommended to use the foreign-data wrapper
-    <literal>dblink_fdw</literal> when defining the corresponding foreign
-    server.  See the example below, as well as the following:
-    <simplelist type="inline">
-     <member><xref linkend="sql-createserver"></member>
-     <member><xref linkend="sql-createusermapping"></member>
-    </simplelist>
+    <literal>dblink_fdw</literal> when defining the foreign
+    server.  See the example below, as well as
+    <xref linkend="sql-createserver"> and
+    <xref linkend="sql-createusermapping">.
    </para>
 
   </refsect1>
@@ -77,8 +80,8 @@ dblink_connect(text connname, text connstr) returns text
       <para><application>libpq</>-style connection info string, for example
        <literal>hostaddr=127.0.0.1 port=5432 dbname=mydb user=postgres
        password=mypasswd</>.
-       For details see <function>PQconnectdb</> in
-       <xref linkend="libpq-connect">.
+       For details see <xref linkend="libpq-connstring">.
+       Alternatively, the name of a foreign server.
       </para>
      </listitem>
     </varlistentry>
@@ -133,9 +136,10 @@ SELECT dblink_connect('myconn', 'dbname=postgres');
 --       ERROR:  password is required
 --       DETAIL:  Non-superuser cannot connect if the server does not request a password.
 --       HINT:  Target server's authentication method must be changed.
-CREATE USER dblink_regression_test WITH PASSWORD 'secret';
+
 CREATE SERVER fdtest FOREIGN DATA WRAPPER dblink_fdw OPTIONS (hostaddr '127.0.0.1', dbname 'contrib_regression');
 
+CREATE USER dblink_regression_test WITH PASSWORD 'secret';
 CREATE USER MAPPING FOR dblink_regression_test SERVER fdtest OPTIONS (user 'dblink_regression_test', password 'secret');
 GRANT USAGE ON FOREIGN SERVER fdtest TO dblink_regression_test;
 GRANT SELECT ON TABLE foo TO dblink_regression_test;
@@ -166,7 +170,7 @@ SELECT * FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[])
 
 \c - :ORIGINAL_USER
 REVOKE USAGE ON FOREIGN SERVER fdtest FROM dblink_regression_test;
-REVOKE SELECT ON TABLE foo FROM  dblink_regression_test;
+REVOKE SELECT ON TABLE foo FROM dblink_regression_test;
 DROP USER MAPPING FOR dblink_regression_test SERVER fdtest;
 DROP USER dblink_regression_test;
 DROP SERVER fdtest;
diff --git a/doc/src/sgml/filelist.sgml b/doc/src/sgml/filelist.sgml
index 368f9321c88138517bc30c9f2192bc0812d5d5bd..5d55ef357b0ba3579b1ca0224a235acc2be1efd5 100644
--- a/doc/src/sgml/filelist.sgml
+++ b/doc/src/sgml/filelist.sgml
@@ -134,6 +134,7 @@
 <!ENTITY pgtesttiming    SYSTEM "pgtesttiming.sgml">
 <!ENTITY pgtrgm          SYSTEM "pgtrgm.sgml">
 <!ENTITY pgupgrade       SYSTEM "pgupgrade.sgml">
+<!ENTITY postgres-fdw    SYSTEM "postgres-fdw.sgml">
 <!ENTITY seg             SYSTEM "seg.sgml">
 <!ENTITY contrib-spi     SYSTEM "contrib-spi.sgml">
 <!ENTITY sepgsql         SYSTEM "sepgsql.sgml">
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index aa2ec2ab7bb1f834c52d347d54dbd42001195ae0..775d25054f8280dd9ca5c11a41ff3a6d2d7eb39e 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -6941,7 +6941,7 @@ myEventProc(PGEventId evtId, void *evtInfo, void *passThrough)
   <para>
    The file uses an <quote>INI file</quote> format where the section
    name is the service name and the parameters are connection
-   parameters; see <xref linkend="libpq-connect"> for a list.  For
+   parameters; see <xref linkend="libpq-paramkeywords"> for a list.  For
    example:
 <programlisting>
 # comment
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
new file mode 100644
index 0000000000000000000000000000000000000000..61b77774aeecf79add1476f15f8cbff794befded
--- /dev/null
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -0,0 +1,325 @@
+<!-- doc/src/sgml/postgres-fdw.sgml -->
+
+<sect1 id="postgres-fdw" xreflabel="postgres_fdw">
+ <title>postgres_fdw</title>
+
+ <indexterm zone="postgres-fdw">
+  <primary>postgres_fdw</primary>
+ </indexterm>
+
+ <para>
+  The <filename>postgres_fdw</> module provides the foreign-data wrapper
+  <literal>postgres_fdw</literal>, which can be used to access data
+  stored in external <productname>PostgreSQL</productname> servers.
+ </para>
+
+ <para>
+  The functionality provided by this module overlaps substantially
+  with the functionality of the older <xref linkend="dblink"> module.
+  But <filename>postgres_fdw</> provides more transparent and
+  standards-compliant syntax for accessing remote tables, and can give
+  better performance in many cases.
+ </para>
+
+ <para>
+  To prepare for remote access using <filename>postgres_fdw</>:
+  <orderedlist spacing="compact">
+   <listitem>
+    <para>
+     Install the  <filename>postgres_fdw</> extension using <xref
+     linkend="sql-createextension">.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     Create a foreign server object, using <xref linkend="sql-createserver">,
+     to represent each remote database you want to connect to.
+     Specify connection information, except <literal>user</literal> and
+     <literal>password</literal>, as options of the server object.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     Create a user mapping, using <xref linkend="sql-createusermapping">, for
+     each database user you want to allow to access each foreign server.
+     Specify the remote user name and password to use as
+     <literal>user</literal> and <literal>password</literal> options of the
+     user mapping.
+    </para>
+   </listitem>
+   <listitem>
+    <para>
+     Create a foreign table, using <xref linkend="sql-createforeigntable">,
+     for each remote table you want to access.  The columns of the foreign
+     table must match the referenced remote table.  You can, however, use
+     table and/or column names different from the remote table's, if you
+     specify the correct remote names as options of the foreign table object.
+    </para>
+   </listitem>
+  </orderedlist>
+ </para>
+
+ <para>
+  Now you need only <command>SELECT</> from a foreign table to access
+  the data stored in its underlying remote table.
+ </para>
+
+ <para>
+  It is generally recommended that the columns of a foreign table be declared
+  with exactly the same data types, and collations if applicable, as the
+  referenced columns of the remote table.  Although <filename>postgres_fdw</>
+  is currently rather forgiving about performing data type conversions at
+  need, surprising semantic anomalies may arise when types or collations do
+  not match, due to the remote server interpreting <literal>WHERE</> clauses
+  slightly differently from the local server.
+ </para>
+
+ <para>
+  Note that a foreign table can be declared with fewer columns, or with a
+  different column order, than its underlying remote table has.  Matching
+  of columns to the remote table is by name, not position.
+ </para>
+
+ <sect2>
+  <title>FDW Options of postgres_fdw</title>
+
+  <sect3>
+   <title>Connection Options</title>
+
+   <para>
+    A foreign server using the <filename>postgres_fdw</> foreign data wrapper
+    can have the same options that <application>libpq</> accepts in
+    connection strings, as described in <xref linkend="libpq-paramkeywords">,
+    except that these options are not allowed:
+
+    <itemizedlist spacing="compact">
+     <listitem>
+      <para>
+       <literal>user</literal> and <literal>password</literal> (specify these
+       for a user mapping, instead)
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       <literal>client_encoding</> (this is automatically set from the local
+       server encoding)
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       <literal>fallback_application_name</> (always set to
+       <literal>postgres_fdw</>)
+      </para>
+     </listitem>
+    </itemizedlist>
+   </para>
+
+   <para>
+    Only superusers may connect to foreign servers without password
+    authentication, so always specify the <literal>password</literal> option
+    for user mappings belonging to non-superusers.
+   </para>
+  </sect3>
+
+  <sect3>
+   <title>Object Name Options</title>
+
+   <para>
+    These options can be used to control the names used in SQL statements
+    sent to the remote <productname>PostgreSQL</productname> server.  These
+    options are needed when a foreign table is created with names different
+    from the underlying remote table's names.
+   </para>
+
+   <variablelist>
+
+    <varlistentry>
+     <term><literal>schema_name</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a foreign table, gives the
+       schema name to use for the foreign table on the remote server.  If this
+       option is omitted, the name of the foreign table's schema is used.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal>table_name</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a foreign table, gives the
+       table name to use for the foreign table on the remote server.  If this
+       option is omitted, the foreign table's name is used.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal>column_name</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a column of a foreign table,
+       gives the column name to use for the column on the remote server.
+       If this option is omitted, the column's name is used.
+      </para>
+     </listitem>
+    </varlistentry>
+
+   </variablelist>
+
+  </sect3>
+
+  <sect3>
+   <title>Cost Estimation Options</title>
+
+   <para>
+    <filename>postgres_fdw</> retrieves remote data by executing queries
+    against remote servers, so ideally the estimated cost of scanning a
+    foreign table should be whatever it costs to be done on the remote
+    server, plus some overhead for communication.  The most reliable way to
+    get such an estimate is to ask the remote server and then add something
+    for overhead &mdash; but for simple queries, it may not be worth the cost
+    of an additional remote query to get a cost estimate.
+    So <filename>postgres_fdw</> provides the following options to control
+    how cost estimation is done:
+   </para>
+
+   <variablelist>
+
+    <varlistentry>
+     <term><literal>use_remote_estimate</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a foreign table or a foreign
+       server, controls whether <filename>postgres_fdw</> issues remote
+       <command>EXPLAIN</command> commands to obtain cost estimates.
+       A setting for a foreign table overrides any setting for its server,
+       but only for that table.
+       The default is <literal>false</literal>.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal>fdw_startup_cost</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a foreign server, is a numeric
+       value that is added to the estimated startup cost of any foreign-table
+       scan on that server.  This represents the additional overhead of
+       establishing a connection, parsing and planning the query on the
+       remote side, etc.
+       The default value is <literal>100</literal>.
+      </para>
+     </listitem>
+    </varlistentry>
+
+    <varlistentry>
+     <term><literal>fdw_tuple_cost</literal></term>
+     <listitem>
+      <para>
+       This option, which can be specified for a foreign server, is a numeric
+       value that is used as extra cost per-tuple for foreign-table
+       scans on that server.  This represents the additional overhead of
+       data transfer between servers.  You might increase or decrease this
+       number to reflect higher or lower network delay to the remote server.
+       The default value is <literal>0.01</literal>.
+      </para>
+     </listitem>
+    </varlistentry>
+
+   </variablelist>
+
+   <para>
+    When <literal>use_remote_estimate</literal> is true,
+    <filename>postgres_fdw</> obtains rowcount and cost estimates from the
+    remote server and then adds <literal>fdw_startup_cost</literal> and
+    <literal>fdw_tuple_cost</literal> to the cost estimates.  When
+    <literal>use_remote_estimate</literal> is false,
+    <filename>postgres_fdw</> performs local rowcount and cost estimation
+    and then adds <literal>fdw_startup_cost</literal> and
+    <literal>fdw_tuple_cost</literal> to the cost estimates.  This local
+    estimation is unlikely to be very accurate unless local copies of the
+    remote table's statistics are available.  Running
+    <xref linkend="sql-analyze"> on the foreign table is the way to update
+    the local statistics; this will perform a scan of the remote table and
+    then calculate and store statistics just as though the table were local.
+    Keeping local statistics can be a useful way to reduce per-query planning
+    overhead for a remote table &mdash; but if the remote table is
+    frequently updated, the local statistics will soon be obsolete.
+   </para>
+
+  </sect3>
+ </sect2>
+
+ <sect2>
+  <title>Connection Management</title>
+
+  <para>
+   <filename>postgres_fdw</filename> establishes a connection to a
+   foreign server during the first query that uses a foreign table
+   associated with the foreign server.  This connection is kept and
+   re-used for subsequent queries in the same session.  However, if
+   multiple user identities (user mappings) are used to access the foreign
+   server, a connection is established for each user mapping.
+  </para>
+ </sect2>
+
+ <sect2>
+  <title>Transaction Management</title>
+
+  <para>
+   During a query that references any remote tables on a foreign server,
+   <filename>postgres_fdw</filename> opens a transaction on the
+   remote server if one is not already open corresponding to the current
+   local transaction.  The remote transaction is committed or aborted when
+   the local transaction commits or aborts.  Savepoints are similarly
+   managed by creating corresponding remote savepoints.
+  </para>
+
+  <para>
+   The remote transaction uses <literal>SERIALIZABLE</>
+   isolation level when the local transaction has <literal>SERIALIZABLE</>
+   isolation level; otherwise it uses <literal>REPEATABLE READ</>
+   isolation level.  This choice ensures that if a query performs multiple
+   table scans on the remote server, it will get snapshot-consistent results
+   for all the scans.  A consequence is that successive queries within a
+   single transaction will see the same data from the remote server, even if
+   concurrent updates are occurring on the remote server due to other
+   activities.  That behavior would be expected anyway if the local
+   transaction uses <literal>SERIALIZABLE</> or <literal>REPEATABLE READ</>
+   isolation level, but it might be surprising for a <literal>READ
+   COMMITTED</> local transaction.  A future
+   <productname>PostgreSQL</productname> release might modify these rules.
+  </para>
+ </sect2>
+
+ <sect2>
+  <title>Remote Query Optimization</title>
+
+  <para>
+   <filename>postgres_fdw</> attempts to optimize remote queries to reduce
+   the amount of data transferred from foreign servers.  This is done by
+   sending query <literal>WHERE</> clauses to the remote server for
+   execution, and by not retrieving table columns that are not needed for
+   the current query.  To reduce the risk of misexecution of queries,
+   <literal>WHERE</> clauses are not sent to the remote server unless they use
+   only built-in data types, operators, and functions.  Operators and
+   functions in the clauses must be <literal>IMMUTABLE</> as well.
+  </para>
+
+  <para>
+   The query that is actually sent to the remote server for execution can
+   be examined using <command>EXPLAIN VERBOSE</>.
+  </para>
+ </sect2>
+
+ <sect2>
+  <title>Author</title>
+  <para>
+   Shigeru Hanada <email>shigeru.hanada@gmail.com</email>
+  </para>
+ </sect2>
+
+</sect1>
diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml
index caa9f1b3389e5ce57e2e50d13011e41c0ed3d11b..d7b0d731b9dbf606ca294359f7ca92b48416c6c0 100644
--- a/doc/src/sgml/queries.sgml
+++ b/doc/src/sgml/queries.sgml
@@ -699,7 +699,7 @@ SELECT *
     WHERE proname LIKE 'bytea%';
 </programlisting>
      The <xref linkend="CONTRIB-DBLINK-FUNCTION"> function
-     (part of the <xref linkend="dblink"> module>) executes
+     (part of the <xref linkend="dblink"> module) executes
      a remote query.  It is declared to return
      <type>record</> since it might be used for any kind of query.
      The actual column set must be specified in the calling query so
diff --git a/doc/src/sgml/recovery-config.sgml b/doc/src/sgml/recovery-config.sgml
index 7e39c0db75ad5cf01e4566f830d6aa54dbf1ef30..c0c543e7a4bada87e95ee21b48bfdee8bd7e6055 100644
--- a/doc/src/sgml/recovery-config.sgml
+++ b/doc/src/sgml/recovery-config.sgml
@@ -314,8 +314,7 @@ restore_command = 'copy "C:\\server\\archivedir\\%f" "%p"'  # Windows
          <para>
           Specifies a connection string to be used for the standby server
           to connect with the primary. This string is in the format
-          accepted by the libpq <function>PQconnectdb</function> function,
-          described in <xref linkend="libpq-connect">. If any option is
+          described in <xref linkend="libpq-connstring">. If any option is
           unspecified in this string, then the corresponding environment
           variable (see <xref linkend="libpq-envars">) is checked. If the
           environment variable is not set either, then
diff --git a/doc/src/sgml/ref/create_foreign_data_wrapper.sgml b/doc/src/sgml/ref/create_foreign_data_wrapper.sgml
index 804fb47c68fd0a97c319d2137c471c8e21436859..d9936e8165999cbb8b6d6d41293596fdb7ab3688 100644
--- a/doc/src/sgml/ref/create_foreign_data_wrapper.sgml
+++ b/doc/src/sgml/ref/create_foreign_data_wrapper.sgml
@@ -121,14 +121,6 @@ CREATE FOREIGN DATA WRAPPER <replaceable class="parameter">name</replaceable>
    There is no support for updating a foreign table, and optimization of
    queries is primitive (and mostly left to the wrapper, too).
   </para>
-
-  <para>
-   There is one built-in foreign-data wrapper validator function
-   provided:
-   <filename>postgresql_fdw_validator</filename>, which accepts
-   options corresponding to <application>libpq</> connection
-   parameters.
-  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_foreign_table.sgml b/doc/src/sgml/ref/create_foreign_table.sgml
index d0b96db055e78c77845d7e5eb82aba9431c4f1c8..0a6ac29d4d995c306b133d9c84ea9bdd40cab42f 100644
--- a/doc/src/sgml/ref/create_foreign_table.sgml
+++ b/doc/src/sgml/ref/create_foreign_table.sgml
@@ -32,7 +32,7 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name
   <title>Description</title>
 
   <para>
-   <command>CREATE FOREIGN TABLE</command> will create a new foreign table
+   <command>CREATE FOREIGN TABLE</command> creates a new foreign table
    in the current database. The table will be owned by the user issuing the
    command.
   </para>
@@ -54,8 +54,9 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name
   </para>
 
   <para>
-   To be able to create a table, you must have <literal>USAGE</literal>
-   privilege on all column types.
+   To be able to create a foreign table, you must have <literal>USAGE</literal>
+   privilege on the foreign server, as well as <literal>USAGE</literal>
+   privilege on all column types used in the table.
   </para>
  </refsect1>
 
@@ -134,7 +135,7 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name
     <term><replaceable class="PARAMETER">server_name</replaceable></term>
     <listitem>
      <para>
-      The name of an existing server for the foreign table.
+      The name of an existing foreign server to use for the foreign table.
       For details on defining a server, see <xref
       linkend="SQL-CREATESERVER">.
      </para>
@@ -164,7 +165,8 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name
   <title>Examples</title>
 
   <para>
-   Create foreign table <structname>films</> with <structname>film_server</>:
+   Create foreign table <structname>films</>, which will be accessed through
+   the server <structname>film_server</>:
 
 <programlisting>
 CREATE FOREIGN TABLE films (
diff --git a/doc/src/sgml/ref/create_server.sgml b/doc/src/sgml/ref/create_server.sgml
index 60744b2d46329fb7957dc4fce2e9c59c057f9231..3e6127a3898c27d747df74442b51b6c7fa0a93d0 100644
--- a/doc/src/sgml/ref/create_server.sgml
+++ b/doc/src/sgml/ref/create_server.sgml
@@ -110,11 +110,10 @@ CREATE SERVER <replaceable class="parameter">server_name</replaceable> [ TYPE '<
   <title>Notes</title>
 
   <para>
-   When using the <application>dblink</application> module
-   (see <xref linkend="dblink">), the foreign server name can be used
+   When using the <xref linkend="dblink"> module,
+   a foreign server's name can be used
    as an argument of the <xref linkend="contrib-dblink-connect">
-   function to indicate the connection parameters.  See also there for
-   more examples.  It is necessary to have
+   function to indicate the connection parameters.  It is necessary to have
    the <literal>USAGE</literal> privilege on the foreign server to be
    able to use it in this way.
   </para>
@@ -124,19 +123,13 @@ CREATE SERVER <replaceable class="parameter">server_name</replaceable> [ TYPE '<
   <title>Examples</title>
 
   <para>
-   Create a server <literal>foo</> that uses the built-in foreign-data
-   wrapper <literal>default</>:
+   Create a server <literal>myserver</> that uses the
+   foreign-data wrapper <literal>postgres_fdw</>:
 <programlisting>
-CREATE SERVER foo FOREIGN DATA WRAPPER "default";
+CREATE SERVER myserver FOREIGN DATA WRAPPER postgres_fdw OPTIONS (host 'foo', dbname 'foodb', port '5432');
 </programlisting>
+   See <xref linkend="postgres-fdw"> for more details.
   </para>
-
-  <para>
-   Create a server <literal>myserver</> that uses the
-   foreign-data wrapper <literal>pgsql</>:
-<programlisting>
-CREATE SERVER myserver FOREIGN DATA WRAPPER pgsql OPTIONS (host 'foo', dbname 'foodb', port '5432');
-</programlisting></para>
  </refsect1>
 
  <refsect1>
@@ -154,6 +147,7 @@ CREATE SERVER myserver FOREIGN DATA WRAPPER pgsql OPTIONS (host 'foo', dbname 'f
    <member><xref linkend="sql-alterserver"></member>
    <member><xref linkend="sql-dropserver"></member>
    <member><xref linkend="sql-createforeigndatawrapper"></member>
+   <member><xref linkend="sql-createforeigntable"></member>
    <member><xref linkend="sql-createusermapping"></member>
   </simplelist>
  </refsect1>
diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml
index fb81af425da3881d33262ee8b2123d263b6c22b1..f42d659518730529744e7b996b4c17a3196696b5 100644
--- a/doc/src/sgml/ref/grant.sgml
+++ b/doc/src/sgml/ref/grant.sgml
@@ -357,10 +357,9 @@ GRANT <replaceable class="PARAMETER">role_name</replaceable> [, ...] TO <replace
        to create new servers using that foreign-data wrapper.
       </para>
       <para>
-       For servers, this privilege enables the grantee to create,
-       alter, and drop his own user's user mappings associated with
-       that server.  Also, it enables the grantee to query the options
-       of the server and associated user mappings.
+       For servers, this privilege enables the grantee to create foreign
+       tables using the server, and also to create, alter, or drop his own
+       user's user mappings associated with that server.
       </para>
      </listitem>
     </varlistentry>
diff --git a/doc/src/sgml/ref/pg_isready.sgml b/doc/src/sgml/ref/pg_isready.sgml
index ff80a78305e84d8922e1d89256d9e7a30d75b0b9..407d73ba5bdd7942af117fd8cc66245a633839c7 100644
--- a/doc/src/sgml/ref/pg_isready.sgml
+++ b/doc/src/sgml/ref/pg_isready.sgml
@@ -54,7 +54,8 @@ PostgreSQL documentation
        with a valid <acronym>URI</acronym> prefix
        (<literal>postgresql://</literal>
        or <literal>postgres://</literal>), it is treated as a
-       <parameter>conninfo</parameter> string. See <xref linkend="libpq-connect"> for more information.
+       <parameter>conninfo</parameter> string. See <xref
+       linkend="libpq-connstring"> for more information.
       </para>
       </listitem>
     </varlistentry>
diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml
index 233f747163e8d31d105ca19a7dbe58bfd84d4758..465d3a1882dd3dc1e6da27baae58233ba7628648 100644
--- a/doc/src/sgml/ref/psql-ref.sgml
+++ b/doc/src/sgml/ref/psql-ref.sgml
@@ -120,7 +120,8 @@ PostgreSQL documentation
        with a valid <acronym>URI</acronym> prefix
        (<literal>postgresql://</literal>
        or <literal>postgres://</literal>), it is treated as a
-       <parameter>conninfo</parameter> string. See <xref linkend="libpq-connect"> for more information.
+       <parameter>conninfo</parameter> string. See <xref
+       linkend="libpq-connstring"> for more information.
       </para>
       </listitem>
     </varlistentry>
@@ -608,9 +609,9 @@ PostgreSQL documentation
 $ <userinput>psql "service=myservice sslmode=require"</userinput>
 $ <userinput>psql postgresql://dbmaster:5433/mydb?sslmode=require</userinput>
 </programlisting>
-     This way you can also use <acronym>LDAP</acronym> for connection parameter lookup as
-     described in <xref linkend="libpq-ldap">.
-     See <xref linkend="libpq-connect"> for more information on all the
+     This way you can also use <acronym>LDAP</acronym> for connection
+     parameter lookup as described in <xref linkend="libpq-ldap">.
+     See <xref linkend="libpq-paramkeywords"> for more information on all the
      available connection options.
     </para>
 
diff --git a/doc/src/sgml/runtime.sgml b/doc/src/sgml/runtime.sgml
index d76e1c571059d0f8e0e0f7b022488eee7f5e298f..7dada6b67f970406581c2d85196dac7bf9e9ac9f 100644
--- a/doc/src/sgml/runtime.sgml
+++ b/doc/src/sgml/runtime.sgml
@@ -1751,7 +1751,7 @@ pg_dumpall -p 5432 | psql -d postgres -p 5433
    (<xref linkend="ssl-tcp">). The TCP client must connect using
    <literal>sslmode=verify-ca</> or
    <literal>verify-full</> and have the appropriate root certificate
-   file installed (<xref linkend="libpq-connect">).
+   file installed (<xref linkend="libq-ssl-certificates">).
   </para>
  </sect1>
 
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 872ed1f029c59a3a6511f9e8179fcede0a52e14b..bfcc323924aaebe0e48a1a258929085f81fe0bca 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -485,11 +485,15 @@ is_conninfo_option(const char *option, Oid context)
 
 /*
  * Validate the generic option given to SERVER or USER MAPPING.
- * Raise an ERROR if the option or its value is considered
- * invalid.
+ * Raise an ERROR if the option or its value is considered invalid.
  *
  * Valid server options are all libpq conninfo options except
  * user and password -- these may only appear in USER MAPPING options.
+ *
+ * Caution: this function is deprecated, and is now meant only for testing
+ * purposes, because the list of options it knows about doesn't necessarily
+ * square with those known to whichever libpq instance you might be using.
+ * Inquire of libpq itself, instead.
  */
 Datum
 postgresql_fdw_validator(PG_FUNCTION_ARGS)