diff --git a/contrib/postgres_fdw/deparse.c b/contrib/postgres_fdw/deparse.c
index 59cb053..8f86e50 100644
--- a/contrib/postgres_fdw/deparse.c
+++ b/contrib/postgres_fdw/deparse.c
@@ -44,7 +44,9 @@
 #include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
 #include "commands/defrem.h"
+#include "nodes/makefuncs.h"
 #include "nodes/nodeFuncs.h"
+#include "nodes/plannodes.h"
 #include "optimizer/clauses.h"
 #include "optimizer/var.h"
 #include "parser/parsetree.h"
@@ -89,6 +91,8 @@ typedef struct deparse_expr_cxt
 	RelOptInfo *foreignrel;		/* the foreign relation we are planning for */
 	StringInfo	buf;			/* output buffer to append to */
 	List	  **params_list;	/* exprs that will become remote Params */
+	List	   *outertlist;		/* outer child's target list */
+	List	   *innertlist;		/* inner child's target list */
 } deparse_expr_cxt;
 
 /*
@@ -250,7 +254,7 @@ foreign_expr_walker(Node *node,
 				 * Param's collation, ie it's not safe for it to have a
 				 * non-default collation.
 				 */
-				if (var->varno == glob_cxt->foreignrel->relid &&
+				if (bms_is_member(var->varno, glob_cxt->foreignrel->relids) &&
 					var->varlevelsup == 0)
 				{
 					/* Var belongs to foreign table */
@@ -743,18 +747,22 @@ deparseTargetList(StringInfo buf,
 		if (attr->attisdropped)
 			continue;
 
+		if (!first)
+			appendStringInfoString(buf, ", ");
+		first = false;
+
 		if (have_wholerow ||
 			bms_is_member(i - FirstLowInvalidHeapAttributeNumber,
 						  attrs_used))
 		{
-			if (!first)
-				appendStringInfoString(buf, ", ");
-			first = false;
 
 			deparseColumnRef(buf, rtindex, i, root);
 
-			*retrieved_attrs = lappend_int(*retrieved_attrs, i);
 		}
+		else
+			appendStringInfoString(buf, "NULL");
+
+		*retrieved_attrs = lappend_int(*retrieved_attrs, i);
 	}
 
 	/*
@@ -794,12 +802,14 @@ deparseTargetList(StringInfo buf,
  * so Params and other-relation Vars should be replaced by dummy values.
  */
 void
-appendWhereClause(StringInfo buf,
-				  PlannerInfo *root,
-				  RelOptInfo *baserel,
-				  List *exprs,
-				  bool is_first,
-				  List **params)
+appendConditions(StringInfo buf,
+				 PlannerInfo *root,
+				 RelOptInfo *baserel,
+				 List *outertlist,
+				 List *innertlist,
+				 List *exprs,
+				 const char *prefix,
+				 List **params)
 {
 	deparse_expr_cxt context;
 	int			nestlevel;
@@ -813,6 +823,8 @@ appendWhereClause(StringInfo buf,
 	context.foreignrel = baserel;
 	context.buf = buf;
 	context.params_list = params;
+	context.outertlist = outertlist;
+	context.innertlist = innertlist;
 
 	/* Make sure any constants in the exprs are printed portably */
 	nestlevel = set_transmission_modes();
@@ -820,24 +832,197 @@ appendWhereClause(StringInfo buf,
 	foreach(lc, exprs)
 	{
 		RestrictInfo *ri = (RestrictInfo *) lfirst(lc);
+		Expr	   *expr;
 
-		/* Connect expressions with "AND" and parenthesize each condition. */
-		if (is_first)
-			appendStringInfoString(buf, " WHERE ");
+		/* List element is a RestrictInfo or an Expr */
+		if (IsA(ri, RestrictInfo))
+			expr = ri->clause;
 		else
-			appendStringInfoString(buf, " AND ");
+			expr = (Expr *) lfirst(lc);
+
+		/* Connect expressions with "AND" and parenthesize each condition. */
+		if (prefix)
+			appendStringInfo(buf, "%s", prefix);
 
 		appendStringInfoChar(buf, '(');
-		deparseExpr(ri->clause, &context);
+		deparseExpr(expr, &context);
 		appendStringInfoChar(buf, ')');
 
-		is_first = false;
+		prefix= " AND ";
 	}
 
 	reset_transmission_modes(nestlevel);
 }
 
 /*
+ * Deparse given Var into buf.
+ */
+static TargetEntry *
+deparseJoinVar(Var *node, deparse_expr_cxt *context)
+{
+	const char *side;
+	ListCell   *lc2;
+	TargetEntry *tle = NULL;
+	int			j;
+
+	j = 0;
+	foreach(lc2, context->outertlist)
+	{
+		TargetEntry *childtle = (TargetEntry *) lfirst(lc2);
+
+		if (equal(childtle->expr, node))
+		{
+			tle = copyObject(childtle);
+			side = "l";
+			break;
+		}
+		j++;
+	}
+	if (tle == NULL)
+	{
+		j = 0;
+		foreach(lc2, context->innertlist)
+		{
+			TargetEntry *childtle = (TargetEntry *) lfirst(lc2);
+
+			if (equal(childtle->expr, node))
+			{
+				tle = copyObject(childtle);
+				side = "r";
+				break;
+			}
+			j++;
+		}
+	}
+	Assert(tle);
+
+	if (node->varattno == 0)
+		appendStringInfo(context->buf, "%s", side);
+	else
+		appendStringInfo(context->buf, "%s.a_%d", side, j);
+
+	return tle;
+}
+
+static void
+deparseColumnAliases(StringInfo buf, List *targetlist)
+{
+	int			i;
+	ListCell   *lc;
+
+	i = 0;
+	foreach(lc, targetlist)
+	{
+		TargetEntry *tle = (TargetEntry *) lfirst(lc);
+		Var		   *var = (Var *) tle->expr;
+
+		Assert(IsA(var, Var));
+
+		/* Skip whole-row reference */
+		if (var->varattno == 0)
+			continue;
+
+		/* Deparse column alias for the subquery */
+		if (i > 0)
+			appendStringInfoString(buf, ", ");
+		appendStringInfo(buf, "a_%d", i);
+		i++;
+	}
+}
+
+/*
+ * Construct a SELECT statement which contains join clause.
+ *
+ * We also create an TargetEntry List of the columns being retrieved, which is
+ * returned to *fdw_ps_tlist.
+ *
+ * path_o, tl_o, sql_o are respectively path, targetlist, and remote query
+ * statement of the outer child relation.  postfix _i means those for the inner
+ * child relation.  jointype and joinclauses are information of join method.
+ * fdw_ps_tlist is output parameter to pass target list of the pseudo scan to
+ * caller.
+ */
+void
+deparseJoinSql(StringInfo sql,
+			   PlannerInfo *root,
+			   RelOptInfo *baserel,
+			   Path *path_o,
+			   Path *path_i,
+			   ForeignScan *plan_o,
+			   ForeignScan *plan_i,
+			   const char *sql_o,
+			   const char *sql_i,
+			   JoinType jointype,
+			   List *joinclauses,
+			   List *otherclauses,
+			   List **fdw_ps_tlist)
+{
+	StringInfoData selbuf;		/* buffer for SELECT clause */
+	StringInfoData abuf_o;		/* buffer for column alias list of outer */
+	StringInfoData abuf_i;		/* buffer for column alias list of inner */
+	int			i;
+	ListCell   *lc;
+	const char *jointype_str;
+	deparse_expr_cxt context;
+
+	context.root = root;
+	context.foreignrel = baserel;
+	context.buf = &selbuf;
+	context.params_list = NULL;
+	context.outertlist = plan_o->scan.plan.targetlist;
+	context.innertlist = plan_i->scan.plan.targetlist;
+
+	jointype_str = jointype == JOIN_INNER ? "INNER" :
+				   jointype == JOIN_LEFT ? "LEFT" :
+				   jointype == JOIN_RIGHT ? "RIGHT" :
+				   jointype == JOIN_FULL ? "FULL" : "";
+
+	/* print SELECT clause of the join scan */
+	/* XXX: should extend deparseTargetList()? */
+	initStringInfo(&selbuf);
+	i = 0;
+	foreach(lc, baserel->reltargetlist)
+	{
+		Var		   *var = (Var *) lfirst(lc);
+		TargetEntry *tle;
+
+		if (i > 0)
+			appendStringInfoString(&selbuf, ", ");
+		deparseJoinVar(var, &context);
+
+		tle = makeTargetEntry((Expr *) copyObject(var),
+							  i + 1, pstrdup(""), false);
+		if (fdw_ps_tlist)
+			*fdw_ps_tlist = lappend(*fdw_ps_tlist, copyObject(tle));
+
+		i++;
+	}
+
+	/* Deparse column alias portion of subquery in FROM clause. */
+	initStringInfo(&abuf_o);
+	deparseColumnAliases(&abuf_o, plan_o->scan.plan.targetlist);
+	initStringInfo(&abuf_i);
+	deparseColumnAliases(&abuf_i, plan_i->scan.plan.targetlist);
+
+	/* Construct SELECT statement */
+	appendStringInfo(sql, "SELECT %s FROM", selbuf.data);
+	appendStringInfo(sql, " (%s) l (%s) %s JOIN (%s) r (%s)",
+					 sql_o, abuf_o.data, jointype_str, sql_i, abuf_i.data);
+	/* Append ON clause */
+	if (joinclauses)
+		appendConditions(sql, root, baserel,
+						 plan_o->scan.plan.targetlist,
+						 plan_i->scan.plan.targetlist,
+						 joinclauses, " ON ", NULL);
+	/* Append WHERE clause */
+	if (otherclauses)
+		appendConditions(sql, root, baserel,
+						 plan_o->scan.plan.targetlist,
+						 plan_i->scan.plan.targetlist,
+						 otherclauses, " WHERE ", NULL);
+}
+
+/*
  * deparse remote INSERT statement
  *
  * The statement text is appended to buf, and we also create an integer List
@@ -1261,6 +1446,8 @@ deparseExpr(Expr *node, deparse_expr_cxt *context)
 /*
  * Deparse given Var node into context->buf.
  *
+ * If context has valid innerrel, this is invoked for a join conditions.
+ *
  * If the Var belongs to the foreign relation, just print its remote name.
  * Otherwise, it's effectively a Param (and will in fact be a Param at
  * run time).  Handle it the same way we handle plain Params --- see
@@ -1271,39 +1458,46 @@ deparseVar(Var *node, deparse_expr_cxt *context)
 {
 	StringInfo	buf = context->buf;
 
-	if (node->varno == context->foreignrel->relid &&
-		node->varlevelsup == 0)
+	if (context->foreignrel->reloptkind == RELOPT_JOINREL)
 	{
-		/* Var belongs to foreign table */
-		deparseColumnRef(buf, node->varno, node->varattno, context->root);
+		deparseJoinVar(node, context);
 	}
 	else
 	{
-		/* Treat like a Param */
-		if (context->params_list)
+		if (node->varno == context->foreignrel->relid &&
+			node->varlevelsup == 0)
 		{
-			int			pindex = 0;
-			ListCell   *lc;
-
-			/* find its index in params_list */
-			foreach(lc, *context->params_list)
+			/* Var belongs to foreign table */
+			deparseColumnRef(buf, node->varno, node->varattno, context->root);
+		}
+		else
+		{
+			/* Treat like a Param */
+			if (context->params_list)
 			{
-				pindex++;
-				if (equal(node, (Node *) lfirst(lc)))
-					break;
+				int			pindex = 0;
+				ListCell   *lc;
+
+				/* find its index in params_list */
+				foreach(lc, *context->params_list)
+				{
+					pindex++;
+					if (equal(node, (Node *) lfirst(lc)))
+						break;
+				}
+				if (lc == NULL)
+				{
+					/* not in list, so add it */
+					pindex++;
+					*context->params_list = lappend(*context->params_list, node);
+				}
+
+				printRemoteParam(pindex, node->vartype, node->vartypmod, context);
 			}
-			if (lc == NULL)
+			else
 			{
-				/* not in list, so add it */
-				pindex++;
-				*context->params_list = lappend(*context->params_list, node);
+				printRemotePlaceholder(node->vartype, node->vartypmod, context);
 			}
-
-			printRemoteParam(pindex, node->vartype, node->vartypmod, context);
-		}
-		else
-		{
-			printRemotePlaceholder(node->vartype, node->vartypmod, context);
 		}
 	}
 }
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 583cce7..78a3c20 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -35,6 +35,18 @@ CREATE TABLE "S 1"."T 2" (
 	c2 text,
 	CONSTRAINT t2_pkey PRIMARY KEY (c1)
 );
+CREATE TABLE "S 1"."T 4" (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 5" (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c4 text,
+	CONSTRAINT t5_pkey PRIMARY KEY (c1)
+);
 INSERT INTO "S 1"."T 1"
 	SELECT id,
 	       id % 10,
@@ -49,8 +61,22 @@ INSERT INTO "S 1"."T 2"
 	SELECT id,
 	       'AAA' || to_char(id, 'FM000')
 	FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 4"
+	SELECT id,
+	       id + 1,
+	       'AAA' || to_char(id, 'FM000')
+	FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 2 != 0;	-- delete for outer join tests
+INSERT INTO "S 1"."T 5"
+	SELECT id,
+	       id + 1,
+	       'AAA' || to_char(id, 'FM000')
+	FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 5" WHERE c1 % 3 != 0;	-- delete for outer join tests
 ANALYZE "S 1"."T 1";
 ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 4";
+ANALYZE "S 1"."T 5";
 -- ===================================================================
 -- create foreign tables
 -- ===================================================================
@@ -78,6 +104,16 @@ CREATE FOREIGN TABLE ft2 (
 	c8 user_enum
 ) SERVER loopback;
 ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft5 (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5');
 -- ===================================================================
 -- tests for validator
 -- ===================================================================
@@ -124,7 +160,9 @@ ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
 --------+-------+----------+---------------------------------------+-------------
  public | ft1   | loopback | (schema_name 'S 1', table_name 'T 1') | 
  public | ft2   | loopback | (schema_name 'S 1', table_name 'T 1') | 
-(2 rows)
+ public | ft4   | loopback | (schema_name 'S 1', table_name 'T 4') | 
+ public | ft5   | loopback | (schema_name 'S 1', table_name 'T 5') | 
+(4 rows)
 
 -- Now we should be able to run ANALYZE.
 -- To exercise multiple code paths, we use local stats on ft1
@@ -277,22 +315,6 @@ SELECT COUNT(*) FROM ft1 t1;
   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  
@@ -489,17 +511,12 @@ EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c8 = 'foo';  -- can't
 -- parameterized remote path
 EXPLAIN (VERBOSE, COSTS false)
   SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
-                                                 QUERY PLAN                                                  
--------------------------------------------------------------------------------------------------------------
- Nested Loop
-   Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
-   ->  Foreign Scan on public.ft2 a
-         Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
-         Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 47))
-   ->  Foreign Scan on public.ft2 b
-         Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
-         Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
-(8 rows)
+                                                                                                                                                                                                 QUERY PLAN                                                                                                                                                                                                  
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+   Output: c1, c2, c3, c4, c5, c6, c7, c8, c1, c2, c3, c4, c5, c6, c7, c8
+   Remote SQL: SELECT r.a_0, r.a_1, r.a_2, r.a_3, r.a_4, r.a_5, r.a_6, r.a_7, l.a_0, l.a_1, l.a_2, l.a_3, l.a_4, l.a_5, l.a_6, l.a_7 FROM (SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1") l (a_0, a_1, a_2, a_3, a_4, a_5, a_6, a_7) INNER JOIN (SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 47))) r (a_0, a_1, a_2, a_3, a_4, a_5, a_6, a_7) ON ((r.a_1 = l.a_0))
+(3 rows)
 
 SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
  c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  | c1 | c2 |  c3   |              c4              |            c5            | c6 |     c7     | c8  
@@ -651,21 +668,306 @@ SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
 (4 rows)
 
 -- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- join two tables
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+                                                                                                                            QUERY PLAN                                                                                                                            
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c1, c3
+   ->  Sort
+         Output: c1, c1, c3
+         Sort Key: c3, c1
+         ->  Foreign Scan
+               Output: c1, c1, c3
+               Remote SQL: SELECT r.a_0, r.a_1, l.a_0 FROM (SELECT "C 1", NULL, NULL, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1") l (a_0) INNER JOIN (SELECT "C 1", NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1") r (a_0, a_1) ON ((r.a_0 = l.a_0))
+(8 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1  | c1  
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+                                                                                                                                                                                                       QUERY PLAN                                                                                                                                                                                                       
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c1, c1, c3
+   ->  Sort
+         Output: c1, c1, c1, c3
+         Sort Key: c3, c1
+         ->  Foreign Scan
+               Output: c1, c1, c1, c3
+               Remote SQL: SELECT r.a_0, r.a_1, r.a_2, l.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 4") l (a_0, a_1, a_2) INNER JOIN (SELECT r.a_0, r.a_1, l.a_0 FROM (SELECT "C 1", NULL, NULL, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1") l (a_0) INNER JOIN (SELECT "C 1", NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1") r (a_0, a_1) ON ((r.a_0 = l.a_0))) r (a_0, a_1, a_2) ON ((r.a_0 = l.a_0))
+(8 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1 | c1 
+----+----+----
+ 22 | 22 | 22
+ 24 | 24 | 24
+ 26 | 26 | 26
+ 28 | 28 | 28
+ 30 | 30 | 30
+ 32 | 32 | 32
+ 34 | 34 | 34
+ 36 | 36 | 36
+ 38 | 38 | 38
+ 40 | 40 | 40
+(10 rows)
+
+-- left outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+                                                                                               QUERY PLAN                                                                                                
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c1
+   ->  Sort
+         Output: c1, c1
+         Sort Key: c1, c1
+         ->  Foreign Scan
+               Output: c1, c1
+               Remote SQL: SELECT l.a_0, r.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 4") l (a_0, a_1, a_2) LEFT JOIN (SELECT c1, NULL, NULL FROM "S 1"."T 5") r (a_0, a_1, a_2) ON ((l.a_0 = r.a_0))
+(8 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1 
+----+----
+ 22 |   
+ 24 | 24
+ 26 |   
+ 28 |   
+ 30 | 30
+ 32 |   
+ 34 |   
+ 36 | 36
+ 38 |   
+ 40 |   
+(10 rows)
+
+-- right outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 RIGHT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t2.c1 OFFSET 10 LIMIT 10;
+                                                                                                QUERY PLAN                                                                                               
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c1
+   ->  Sort
+         Output: c1, c1
+         Sort Key: c1
+         ->  Foreign Scan
+               Output: c1, c1
+               Remote SQL: SELECT l.a_0, r.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 5") l (a_0, a_1, a_2) LEFT JOIN (SELECT c1, NULL, NULL FROM "S 1"."T 4") r (a_0, a_1, a_2) ON ((r.a_0 = l.a_0))
+(8 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 RIGHT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1 
+----+----
+    | 33
+ 36 | 36
+    | 39
+ 42 | 42
+    | 45
+ 48 | 48
+    | 51
+ 54 | 54
+    | 57
+ 60 | 60
+(10 rows)
+
+-- full outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+                                                                                            QUERY PLAN                                                                                             
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+   Output: c1, c1
+   Sort Key: c1, c1
+   ->  Foreign Scan
+         Output: c1, c1
+         Remote SQL: SELECT l.a_0, r.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 4") l (a_0, a_1, a_2) FULL JOIN (SELECT c1, NULL, NULL FROM "S 1"."T 5") r (a_0, a_1, a_2) ON ((l.a_0 = r.a_0))
+(6 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1  | c1 
+-----+----
+   2 |   
+   4 |   
+   6 |  6
+   8 |   
+  10 |   
+  12 | 12
+  14 |   
+  16 |   
+  18 | 18
+  20 |   
+  22 |   
+  24 | 24
+  26 |   
+  28 |   
+  30 | 30
+  32 |   
+  34 |   
+  36 | 36
+  38 |   
+  40 |   
+  42 | 42
+  44 |   
+  46 |   
+  48 | 48
+  50 |   
+  52 |   
+  54 | 54
+  56 |   
+  58 |   
+  60 | 60
+  62 |   
+  64 |   
+  66 | 66
+  68 |   
+  70 |   
+  72 | 72
+  74 |   
+  76 |   
+  78 | 78
+  80 |   
+  82 |   
+  84 | 84
+  86 |   
+  88 |   
+  90 | 90
+  92 |   
+  94 |   
+  96 | 96
+  98 |   
+ 100 |   
+     |  3
+     |  9
+     | 15
+     | 21
+     | 27
+     | 33
+     | 39
+     | 45
+     | 51
+     | 57
+     | 63
+     | 69
+     | 75
+     | 81
+     | 87
+     | 93
+     | 99
+(67 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1;
+                                                                                                                   QUERY PLAN                                                                                                                   
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+   Output: c1, c1
+   Sort Key: c1, c1
+   ->  Foreign Scan
+         Output: c1, c1
+         Remote SQL: SELECT l.a_0, r.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 4") l (a_0, a_1, a_2) FULL JOIN (SELECT c1, NULL, NULL FROM "S 1"."T 5") r (a_0, a_1, a_2) ON ((l.a_0 = r.a_0)) WHERE (((l.a_0 = r.a_0) OR (l.a_0 IS NULL)))
+(6 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1;
+ c1 | c1 
+----+----
+  6 |  6
+ 12 | 12
+ 18 | 18
+ 24 | 24
+ 30 | 30
+ 36 | 36
+ 42 | 42
+ 48 | 48
+ 54 | 54
+ 60 | 60
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+    |  3
+    |  9
+    | 15
+    | 21
+    | 27
+    | 33
+    | 39
+    | 45
+    | 51
+    | 57
+    | 63
+    | 69
+    | 75
+    | 81
+    | 87
+    | 93
+    | 99
+(33 rows)
+
+-- join at WHERE clause 
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON true WHERE (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+                                                                                                QUERY PLAN                                                                                                 
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+   Output: c1, c1
+   ->  Sort
+         Output: c1, c1
+         Sort Key: c1
+         ->  Foreign Scan
+               Output: c1, c1
+               Remote SQL: SELECT l.a_0, r.a_0 FROM (SELECT c1, NULL, NULL FROM "S 1"."T 4") l (a_0, a_1, a_2) INNER JOIN (SELECT c1, NULL, NULL FROM "S 1"."T 5") r (a_0, a_1, a_2) ON ((l.a_0 = r.a_0))
+(8 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON true WHERE (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1 
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+(6 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                             
---------------------------------------------------------------------
+                                                  QUERY PLAN                                                  
+--------------------------------------------------------------------------------------------------------------
  Nested Loop
    Output: t1.c3, t2.c3
    ->  Foreign Scan on public.ft1 t1
          Output: t1.c3
-         Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+         Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" = 1))
    ->  Foreign Scan on public.ft2 t2
          Output: t2.c3
-         Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" = 2))
+         Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" = 2))
 (8 rows)
 
 EXECUTE st1(1, 1);
@@ -683,8 +985,8 @@ EXECUTE st1(101, 101);
 -- subquery using stable function (can't be sent to remote)
 PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
 EXPLAIN (VERBOSE, COSTS false) EXECUTE st2(10, 20);
-                                                QUERY PLAN                                                
-----------------------------------------------------------------------------------------------------------
+                                                       QUERY PLAN                                                        
+-------------------------------------------------------------------------------------------------------------------------
  Sort
    Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
    Sort Key: t1.c1
@@ -699,7 +1001,7 @@ EXPLAIN (VERBOSE, COSTS false) EXECUTE st2(10, 20);
                ->  Foreign Scan on public.ft2 t2
                      Output: t2.c3
                      Filter: (date(t2.c4) = '01-17-1970'::date)
-                     Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+                     Remote SQL: SELECT NULL, NULL, c3, c4, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" > 10))
 (15 rows)
 
 EXECUTE st2(10, 20);
@@ -717,8 +1019,8 @@ EXECUTE st2(101, 121);
 -- 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 date(c5) = '1970-01-17'::date) ORDER BY c1;
 EXPLAIN (VERBOSE, COSTS false) EXECUTE st3(10, 20);
-                                                      QUERY PLAN                                                       
------------------------------------------------------------------------------------------------------------------------
+                                                                           QUERY PLAN                                                                            
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------
  Sort
    Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
    Sort Key: t1.c1
@@ -732,7 +1034,7 @@ EXPLAIN (VERBOSE, COSTS false) EXECUTE st3(10, 20);
                Output: t2.c3
                ->  Foreign Scan on public.ft2 t2
                      Output: t2.c3
-                     Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+                     Remote SQL: SELECT NULL, NULL, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
 (14 rows)
 
 EXECUTE st3(10, 20);
@@ -1085,7 +1387,7 @@ INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
                Output: ((ft2_1.c1 + 1000)), ((ft2_1.c2 + 100)), ((ft2_1.c3 || ft2_1.c3))
                ->  Foreign Scan on public.ft2 ft2_1
                      Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
-                     Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+                     Remote SQL: SELECT "C 1", c2, c3, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1"
 (9 rows)
 
 INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
@@ -1219,7 +1521,7 @@ UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
          Hash Cond: (ft2.c2 = ft1.c1)
          ->  Foreign Scan on public.ft2
                Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c8, ft2.ctid
-               Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+               Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, NULL, c8, ctid FROM "S 1"."T 1" FOR UPDATE
          ->  Hash
                Output: ft1.*, ft1.c1
                ->  Foreign Scan on public.ft1
@@ -1231,14 +1533,14 @@ UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
   FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
 EXPLAIN (verbose, costs off)
   DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
-                                       QUERY PLAN                                       
-----------------------------------------------------------------------------------------
+                                                               QUERY PLAN                                                               
+----------------------------------------------------------------------------------------------------------------------------------------
  Delete on public.ft2
    Output: c1, c4
-   Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c4
+   Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", NULL, NULL, c4, NULL, NULL, NULL, NULL
    ->  Foreign Scan on public.ft2
          Output: ctid
-         Remote SQL: SELECT ctid FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) FOR UPDATE
+         Remote SQL: SELECT NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, ctid FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) FOR UPDATE
 (6 rows)
 
 DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
@@ -1360,7 +1662,7 @@ DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
          Hash Cond: (ft2.c2 = ft1.c1)
          ->  Foreign Scan on public.ft2
                Output: ft2.ctid, ft2.c2
-               Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" FOR UPDATE
+               Remote SQL: SELECT NULL, c2, NULL, NULL, NULL, NULL, NULL, NULL, ctid FROM "S 1"."T 1" FOR UPDATE
          ->  Hash
                Output: ft1.*, ft1.c1
                ->  Foreign Scan on public.ft1
@@ -2594,12 +2896,12 @@ select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
 -- Consistent check constraints provide consistent results
 ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
 EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 < 0;
-                            QUERY PLAN                             
--------------------------------------------------------------------
+                                                 QUERY PLAN                                                  
+-------------------------------------------------------------------------------------------------------------
  Aggregate
    Output: count(*)
    ->  Foreign Scan on public.ft1
-         Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
+         Remote SQL: SELECT NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE ((c2 < 0))
 (4 rows)
 
 SELECT count(*) FROM ft1 WHERE c2 < 0;
@@ -2638,12 +2940,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
 -- But inconsistent check constraints provide inconsistent results
 ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
 EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 >= 0;
-                             QUERY PLAN                             
---------------------------------------------------------------------
+                                                  QUERY PLAN                                                  
+--------------------------------------------------------------------------------------------------------------
  Aggregate
    Output: count(*)
    ->  Foreign Scan on public.ft1
-         Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
+         Remote SQL: SELECT NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL FROM "S 1"."T 1" WHERE ((c2 >= 0))
 (4 rows)
 
 SELECT count(*) FROM ft1 WHERE c2 >= 0;
diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c
index 63f0577..c35cd54 100644
--- a/contrib/postgres_fdw/postgres_fdw.c
+++ b/contrib/postgres_fdw/postgres_fdw.c
@@ -48,7 +48,8 @@ PG_MODULE_MAGIC;
 
 /*
  * FDW-specific planner information kept in RelOptInfo.fdw_private for a
- * foreign table.  This information is collected by postgresGetForeignRelSize.
+ * foreign table or foreign join.  This information is collected by
+ * postgresGetForeignRelSize, or calculated from join source relations.
  */
 typedef struct PgFdwRelationInfo
 {
@@ -78,10 +79,31 @@ typedef struct PgFdwRelationInfo
 	ForeignTable *table;
 	ForeignServer *server;
 	UserMapping *user;			/* only set in use_remote_estimate mode */
+	Oid			checkAsUser;
 } PgFdwRelationInfo;
 
 /*
- * Indexes of FDW-private information stored in fdw_private lists.
+ * Indexes of FDW-private information stored in fdw_private of ForeignPath.
+ * We use fdw_private of a ForeighPath when the path represents a join which
+ * can be pushed down to remote side.
+ *
+ * 1) Outer child path node
+ * 2) Inner child path node
+ * 3) Join type number(as an Integer node)
+ * 4) RestrictInfo list of join conditions
+ */
+enum FdwPathPrivateIndex
+{
+	FdwPathPrivateOuterPath,
+	FdwPathPrivateInnerPath,
+	FdwPathPrivateJoinType,
+	FdwPathPrivateJoinClauses,
+	FdwPathPrivateOtherClauses,
+};
+
+/*
+ * Indexes of FDW-private information stored in fdw_private of ForeignScan of
+ * a simple foreign table scan for a SELECT statement.
  *
  * We store various information in ForeignScan.fdw_private to pass it from
  * planner to executor.  Currently we store:
@@ -98,7 +120,11 @@ enum FdwScanPrivateIndex
 	/* SQL statement to execute remotely (as a String node) */
 	FdwScanPrivateSelectSql,
 	/* Integer list of attribute numbers retrieved by the SELECT */
-	FdwScanPrivateRetrievedAttrs
+	FdwScanPrivateRetrievedAttrs,
+	/* Integer value of server for the scan */
+	FdwScanPrivateServerOid,
+	/* Integer value of checkAsUser for the scan */
+	FdwScanPrivatecheckAsUser,
 };
 
 /*
@@ -129,6 +155,7 @@ enum FdwModifyPrivateIndex
 typedef struct PgFdwScanState
 {
 	Relation	rel;			/* relcache entry for the foreign table */
+	TupleDesc	tupdesc;		/* tuple descriptor of the scan */
 	AttInMetadata *attinmeta;	/* attribute datatype conversion metadata */
 
 	/* extracted fdw_private data */
@@ -288,6 +315,15 @@ static bool postgresAnalyzeForeignTable(Relation relation,
 							BlockNumber *totalpages);
 static List *postgresImportForeignSchema(ImportForeignSchemaStmt *stmt,
 							Oid serverOid);
+static void postgresGetForeignJoinPaths(PlannerInfo *root,
+						   RelOptInfo *joinrel,
+						   RelOptInfo *outerrel,
+						   RelOptInfo *innerrel,
+						   JoinType jointype,
+						   SpecialJoinInfo *sjinfo,
+						   SemiAntiJoinFactors *semifactors,
+						   List *restrictlisti,
+						   Relids extra_lateral_rels);
 
 /*
  * Helper functions
@@ -324,6 +360,7 @@ static void analyze_row_processor(PGresult *res, int row,
 static HeapTuple make_tuple_from_result_row(PGresult *res,
 						   int row,
 						   Relation rel,
+						   TupleDesc tupdesc,
 						   AttInMetadata *attinmeta,
 						   List *retrieved_attrs,
 						   MemoryContext temp_context);
@@ -368,6 +405,9 @@ postgres_fdw_handler(PG_FUNCTION_ARGS)
 	/* Support functions for IMPORT FOREIGN SCHEMA */
 	routine->ImportForeignSchema = postgresImportForeignSchema;
 
+	/* Support functions for join push-down */
+	routine->GetForeignJoinPaths = postgresGetForeignJoinPaths;
+
 	PG_RETURN_POINTER(routine);
 }
 
@@ -385,6 +425,7 @@ postgresGetForeignRelSize(PlannerInfo *root,
 {
 	PgFdwRelationInfo *fpinfo;
 	ListCell   *lc;
+	RangeTblEntry *rte;
 
 	/*
 	 * We use PgFdwRelationInfo to pass various information to subsequent
@@ -428,6 +469,13 @@ postgresGetForeignRelSize(PlannerInfo *root,
 	}
 
 	/*
+	 * Retrieve RTE to obtain checkAsUser.  checkAsUser is used to determine
+	 * the user to use to obtain user mapping.
+	 */
+	rte = planner_rt_fetch(baserel->relid, root);
+	fpinfo->checkAsUser = rte->checkAsUser;
+
+	/*
 	 * If the table or the server is configured to use remote estimates,
 	 * identify which user to do remote access as during planning.  This
 	 * should match what ExecCheckRTEPerms() does.  If we fail due to lack of
@@ -435,7 +483,6 @@ postgresGetForeignRelSize(PlannerInfo *root,
 	 */
 	if (fpinfo->use_remote_estimate)
 	{
-		RangeTblEntry *rte = planner_rt_fetch(baserel->relid, root);
 		Oid			userid = rte->checkAsUser ? rte->checkAsUser : GetUserId();
 
 		fpinfo->user = GetUserMapping(userid, fpinfo->server->serverid);
@@ -752,6 +799,8 @@ postgresGetForeignPlan(PlannerInfo *root,
 	List	   *retrieved_attrs;
 	StringInfoData sql;
 	ListCell   *lc;
+	List	   *fdw_ps_tlist = NIL;
+	ForeignScan *scan;
 
 	/*
 	 * Separate the scan_clauses into those that can be executed remotely and
@@ -769,7 +818,7 @@ postgresGetForeignPlan(PlannerInfo *root,
 	 * This code must match "extract_actual_clauses(scan_clauses, false)"
 	 * except for the additional decision about remote versus local execution.
 	 * Note however that we only strip the RestrictInfo nodes from the
-	 * local_exprs list, since appendWhereClause expects a list of
+	 * local_exprs list, since appendConditions expects a list of
 	 * RestrictInfos.
 	 */
 	foreach(lc, scan_clauses)
@@ -797,64 +846,127 @@ postgresGetForeignPlan(PlannerInfo *root,
 	 * expressions to be sent as parameters.
 	 */
 	initStringInfo(&sql);
-	deparseSelectSql(&sql, root, baserel, fpinfo->attrs_used,
-					 &retrieved_attrs);
-	if (remote_conds)
-		appendWhereClause(&sql, root, baserel, remote_conds,
-						  true, &params_list);
-
-	/*
-	 * Add FOR UPDATE/SHARE if appropriate.  We apply locking during the
-	 * initial row fetch, rather than later on as is done for local tables.
-	 * The extra roundtrips involved in trying to duplicate the local
-	 * semantics exactly don't seem worthwhile (see also comments for
-	 * RowMarkType).
-	 *
-	 * Note: because we actually run the query as a cursor, this assumes that
-	 * DECLARE CURSOR ... FOR UPDATE is supported, which it isn't before 8.3.
-	 */
-	if (baserel->relid == root->parse->resultRelation &&
-		(root->parse->commandType == CMD_UPDATE ||
-		 root->parse->commandType == CMD_DELETE))
-	{
-		/* Relation is UPDATE/DELETE target, so use FOR UPDATE */
-		appendStringInfoString(&sql, " FOR UPDATE");
-	}
-	else
+	if (scan_relid > 0)
 	{
-		RowMarkClause *rc = get_parse_rowmark(root->parse, baserel->relid);
+		deparseSelectSql(&sql, root, baserel, fpinfo->attrs_used,
+						 &retrieved_attrs);
+		if (remote_conds)
+			appendConditions(&sql, root, baserel, NULL, NULL,
+							 remote_conds, " WHERE ", &params_list);
 
-		if (rc)
+		/*
+		 * Add FOR UPDATE/SHARE if appropriate.  We apply locking during the
+		 * initial row fetch, rather than later on as is done for local tables.
+		 * The extra roundtrips involved in trying to duplicate the local
+		 * semantics exactly don't seem worthwhile (see also comments for
+		 * RowMarkType).
+		 *
+		 * Note: because we actually run the query as a cursor, this assumes
+		 * that DECLARE CURSOR ... FOR UPDATE is supported, which it isn't
+		 * before 8.3.
+		 */
+		if (baserel->relid == root->parse->resultRelation &&
+			(root->parse->commandType == CMD_UPDATE ||
+			 root->parse->commandType == CMD_DELETE))
 		{
-			/*
-			 * Relation is specified as a FOR UPDATE/SHARE target, so handle
-			 * that.
-			 *
-			 * For now, just ignore any [NO] KEY specification, since (a) it's
-			 * not clear what that means for a remote table that we don't have
-			 * complete information about, and (b) it wouldn't work anyway on
-			 * older remote servers.  Likewise, we don't worry about NOWAIT.
-			 */
-			switch (rc->strength)
+			/* Relation is UPDATE/DELETE target, so use FOR UPDATE */
+			appendStringInfoString(&sql, " FOR UPDATE");
+		}
+		else
+		{
+			RowMarkClause *rc = get_parse_rowmark(root->parse, baserel->relid);
+
+			if (rc)
 			{
-				case LCS_FORKEYSHARE:
-				case LCS_FORSHARE:
-					appendStringInfoString(&sql, " FOR SHARE");
-					break;
-				case LCS_FORNOKEYUPDATE:
-				case LCS_FORUPDATE:
-					appendStringInfoString(&sql, " FOR UPDATE");
-					break;
+				/*
+				 * Relation is specified as a FOR UPDATE/SHARE target, so handle
+				 * that.
+				 *
+				 * For now, just ignore any [NO] KEY specification, since (a)
+				 * it's not clear what that means for a remote table that we
+				 * don't have complete information about, and (b) it wouldn't
+				 * work anyway on older remote servers.  Likewise, we don't
+				 * worry about NOWAIT.
+				 */
+				switch (rc->strength)
+				{
+					case LCS_FORKEYSHARE:
+					case LCS_FORSHARE:
+						appendStringInfoString(&sql, " FOR SHARE");
+						break;
+					case LCS_FORNOKEYUPDATE:
+					case LCS_FORUPDATE:
+						appendStringInfoString(&sql, " FOR UPDATE");
+						break;
+				}
 			}
 		}
 	}
+	else
+	{
+		/* Join case */
+		Path	   *path_o;
+		Path	   *path_i;
+		const char *sql_o;
+		const char *sql_i;
+		ForeignScan *plan_o;
+		ForeignScan *plan_i;
+		JoinType	jointype;
+		List	   *joinclauses;
+		List	   *otherclauses;
+		int			i;
+
+		/*
+		 * Retrieve infomation from fdw_private.
+		 */
+		path_o = list_nth(best_path->fdw_private, FdwPathPrivateOuterPath);
+		path_i = list_nth(best_path->fdw_private, FdwPathPrivateInnerPath);
+		jointype = intVal(list_nth(best_path->fdw_private,
+								   FdwPathPrivateJoinType));
+		joinclauses = list_nth(best_path->fdw_private,
+							   FdwPathPrivateJoinClauses);
+		otherclauses = list_nth(best_path->fdw_private,
+								FdwPathPrivateOtherClauses);
+
+		/*
+		 * Construct remote query from bottom to the top.  ForeignScan plan
+		 * node of underlying scans are node necessary for execute the plan
+		 * tree, but it is handy to construct remote query recursively.
+		 */
+		plan_o = (ForeignScan *) create_plan_recurse(root, path_o);
+		Assert(IsA(plan_o, ForeignScan));
+		sql_o = strVal(list_nth(plan_o->fdw_private, FdwScanPrivateSelectSql));
+
+		plan_i = (ForeignScan *) create_plan_recurse(root, path_i);
+		Assert(IsA(plan_i, ForeignScan));
+		sql_i = strVal(list_nth(plan_i->fdw_private, FdwScanPrivateSelectSql));
+
+		deparseJoinSql(&sql, root, baserel, path_o, path_i, plan_o, plan_i,
+					   sql_o, sql_i, jointype, joinclauses, otherclauses,
+					   &fdw_ps_tlist);
+		retrieved_attrs = NIL;
+		for (i = 0; i < list_length(fdw_ps_tlist); i++)
+			retrieved_attrs = lappend_int(retrieved_attrs, i + 1);
+	}
 
 	/*
 	 * Build the fdw_private list that will be available to the executor.
 	 * Items in the list must match enum FdwScanPrivateIndex, above.
 	 */
-	fdw_private = list_make2(makeString(sql.data),
-							 retrieved_attrs);
+	fdw_private = list_make2(makeString(sql.data), retrieved_attrs);
+
+	/*
+	 * In pseudo scan case such as join push-down, add OID of server and
+	 * checkAsUser as extra information.
+	 * XXX: passing serverid and checkAsUser might simplify code through
+	 * all cases, simple scans and join push-down.
+	 */
+	if (scan_relid == 0)
+	{
+		fdw_private = lappend(fdw_private,
+							  makeInteger(fpinfo->server->serverid));
+		fdw_private = lappend(fdw_private, makeInteger(fpinfo->checkAsUser));
+	}
 
 	/*
 	 * Create the ForeignScan node from target list, local filtering
@@ -864,11 +976,18 @@ postgresGetForeignPlan(PlannerInfo *root,
 	 * field of the finished plan node; we can't keep them in private state
 	 * because then they wouldn't be subject to later planner processing.
 	 */
-	return make_foreignscan(tlist,
+	scan = make_foreignscan(tlist,
 							local_exprs,
 							scan_relid,
 							params_list,
 							fdw_private);
+
+	/*
+	 * set fdw_ps_tlist to handle tuples generated by this scan.
+	 */
+	scan->fdw_ps_tlist = fdw_ps_tlist;
+
+	return scan;
 }
 
 /*
@@ -881,9 +1000,8 @@ postgresBeginForeignScan(ForeignScanState *node, int eflags)
 	ForeignScan *fsplan = (ForeignScan *) node->ss.ps.plan;
 	EState	   *estate = node->ss.ps.state;
 	PgFdwScanState *fsstate;
-	RangeTblEntry *rte;
+	Oid			serverid;
 	Oid			userid;
-	ForeignTable *table;
 	ForeignServer *server;
 	UserMapping *user;
 	int			numParams;
@@ -903,22 +1021,51 @@ postgresBeginForeignScan(ForeignScanState *node, int eflags)
 	node->fdw_state = (void *) fsstate;
 
 	/*
-	 * Identify which user to do the remote access as.  This should match what
-	 * ExecCheckRTEPerms() does.
+	 * Initialize fsstate.
+	 *
+	 * These values should be determined.
+	 * - fsstate->rel, NULL if no actual relation
+	 * - serverid, OID of forign server to use for the scan
+	 * - userid, searching user mapping
 	 */
-	rte = rt_fetch(fsplan->scan.scanrelid, estate->es_range_table);
-	userid = rte->checkAsUser ? rte->checkAsUser : GetUserId();
+	if (fsplan->scan.scanrelid > 0)
+	{
+		/* Simple foreign table scan */
+		RangeTblEntry *rte;
+		ForeignTable *table;
 
-	/* Get info about foreign table. */
-	fsstate->rel = node->ss.ss_currentRelation;
-	table = GetForeignTable(RelationGetRelid(fsstate->rel));
-	server = GetForeignServer(table->serverid);
-	user = GetUserMapping(userid, server->serverid);
+		/*
+		 * 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. */
+		fsstate->rel = node->ss.ss_currentRelation;
+		table = GetForeignTable(RelationGetRelid(fsstate->rel));
+		serverid = table->serverid;
+	}
+	else
+	{
+		Oid		checkAsUser;
+
+		/* Join */
+		fsstate->rel = NULL;	/* No actual relation to scan */
+
+		serverid = intVal(list_nth(fsplan->fdw_private,
+								   FdwScanPrivateServerOid));
+		checkAsUser = intVal(list_nth(fsplan->fdw_private,
+									  FdwScanPrivatecheckAsUser));
+		userid = checkAsUser ? checkAsUser : GetUserId();
+	}
 
 	/*
 	 * Get connection to the foreign server.  Connection manager will
 	 * establish new connection if necessary.
 	 */
+	server = GetForeignServer(serverid);
+	user = GetUserMapping(userid, server->serverid);
 	fsstate->conn = GetConnection(server, user, false);
 
 	/* Assign a unique ID for my cursor */
@@ -929,7 +1076,7 @@ postgresBeginForeignScan(ForeignScanState *node, int eflags)
 	fsstate->query = strVal(list_nth(fsplan->fdw_private,
 									 FdwScanPrivateSelectSql));
 	fsstate->retrieved_attrs = (List *) list_nth(fsplan->fdw_private,
-											   FdwScanPrivateRetrievedAttrs);
+												 FdwScanPrivateRetrievedAttrs);
 
 	/* Create contexts for batches of tuples and per-tuple temp workspace. */
 	fsstate->batch_cxt = AllocSetContextCreate(estate->es_query_cxt,
@@ -944,7 +1091,11 @@ postgresBeginForeignScan(ForeignScanState *node, int eflags)
 											  ALLOCSET_SMALL_MAXSIZE);
 
 	/* Get info we'll need for input data conversion. */
-	fsstate->attinmeta = TupleDescGetAttInMetadata(RelationGetDescr(fsstate->rel));
+	if (fsplan->scan.scanrelid > 0)
+		fsstate->tupdesc = RelationGetDescr(fsstate->rel);
+	else
+		fsstate->tupdesc = node->ss.ss_ScanTupleSlot->tts_tupleDescriptor;
+	fsstate->attinmeta = TupleDescGetAttInMetadata(fsstate->tupdesc);
 
 	/* Prepare for output conversion of parameters used in remote query. */
 	numParams = list_length(fsplan->fdw_exprs);
@@ -1747,11 +1898,13 @@ estimate_path_cost_size(PlannerInfo *root,
 		deparseSelectSql(&sql, root, baserel, fpinfo->attrs_used,
 						 &retrieved_attrs);
 		if (fpinfo->remote_conds)
-			appendWhereClause(&sql, root, baserel, fpinfo->remote_conds,
-							  true, NULL);
+			appendConditions(&sql, root, baserel, NULL, NULL,
+							 fpinfo->remote_conds, " WHERE ", NULL);
 		if (remote_join_conds)
-			appendWhereClause(&sql, root, baserel, remote_join_conds,
-							  (fpinfo->remote_conds == NIL), NULL);
+			appendConditions(&sql, root, baserel, NULL, NULL,
+							 remote_join_conds,
+							 fpinfo->remote_conds == NIL ? " WHERE " : " AND ",
+							 NULL);
 
 		/* Get the remote estimate */
 		conn = GetConnection(fpinfo->server, fpinfo->user, false);
@@ -2052,6 +2205,7 @@ fetch_more_data(ForeignScanState *node)
 			fsstate->tuples[i] =
 				make_tuple_from_result_row(res, i,
 										   fsstate->rel,
+										   fsstate->tupdesc,
 										   fsstate->attinmeta,
 										   fsstate->retrieved_attrs,
 										   fsstate->temp_cxt);
@@ -2270,6 +2424,7 @@ store_returning_result(PgFdwModifyState *fmstate,
 
 		newtup = make_tuple_from_result_row(res, 0,
 											fmstate->rel,
+											RelationGetDescr(fmstate->rel),
 											fmstate->attinmeta,
 											fmstate->retrieved_attrs,
 											fmstate->temp_cxt);
@@ -2562,6 +2717,7 @@ analyze_row_processor(PGresult *res, int row, PgFdwAnalyzeState *astate)
 
 		astate->rows[pos] = make_tuple_from_result_row(res, row,
 													   astate->rel,
+											   RelationGetDescr(astate->rel),
 													   astate->attinmeta,
 													 astate->retrieved_attrs,
 													   astate->temp_cxt);
@@ -2835,6 +2991,246 @@ postgresImportForeignSchema(ImportForeignSchemaStmt *stmt, Oid serverOid)
 }
 
 /*
+ * Construct PgFdwRelationInfo from two join sources
+ */
+static PgFdwRelationInfo *
+merge_fpinfo(PgFdwRelationInfo *fpinfo_o,
+			 PgFdwRelationInfo *fpinfo_i,
+			 JoinType jointype)
+{
+	PgFdwRelationInfo *fpinfo;
+
+	fpinfo = (PgFdwRelationInfo *) palloc0(sizeof(PgFdwRelationInfo));
+	fpinfo->remote_conds = list_concat(copyObject(fpinfo_o->remote_conds),
+									   copyObject(fpinfo_i->remote_conds));
+	fpinfo->local_conds = list_concat(copyObject(fpinfo_o->local_conds),
+									  copyObject(fpinfo_i->local_conds));
+
+	fpinfo->attrs_used = NULL;		/* Use fdw_ps_tlist */
+	fpinfo->local_conds_cost.startup = fpinfo_o->local_conds_cost.startup +
+									   fpinfo_i->local_conds_cost.startup;
+	fpinfo->local_conds_cost.per_tuple = fpinfo_o->local_conds_cost.per_tuple +
+										 fpinfo_i->local_conds_cost.per_tuple;
+	fpinfo->local_conds_sel = fpinfo_o->local_conds_sel *
+							  fpinfo_i->local_conds_sel;
+	if (jointype == JOIN_INNER)
+		fpinfo->rows = Min(fpinfo_o->rows, fpinfo_i->rows);
+	else
+		fpinfo->rows = Max(fpinfo_o->rows, fpinfo_i->rows);
+	fpinfo->rows = Min(fpinfo_o->rows, fpinfo_i->rows);
+	/* XXX we should consider only columns in fdw_ps_tlist */
+	fpinfo->width = fpinfo_o->width + fpinfo_i->width;
+	/* XXX we should estimate better costs */
+
+	fpinfo->use_remote_estimate = false;	/* Never use in join case */
+	fpinfo->fdw_startup_cost = fpinfo_o->fdw_startup_cost;
+	fpinfo->fdw_tuple_cost = fpinfo_o->fdw_tuple_cost;
+
+	fpinfo->startup_cost = fpinfo->fdw_startup_cost;
+	fpinfo->total_cost =
+		fpinfo->startup_cost + fpinfo->fdw_tuple_cost * fpinfo->rows;
+
+	fpinfo->table = NULL;	/* always NULL in join case */
+	fpinfo->server = fpinfo_o->server;
+	fpinfo->user = fpinfo_o->user ? fpinfo_o->user : fpinfo_i->user;
+	/* checkAsuser must be identical */
+	fpinfo->checkAsUser = fpinfo_o->checkAsUser;
+
+	return fpinfo;
+}
+
+/*
+ * postgresGetForeignJoinPaths
+ *		Add possible ForeignPath to joinrel.
+ *
+ * Joins satify conditions below can be pushed down to remote PostgreSQL server.
+ *
+ * 1) Join type is inner or outer
+ * 2) Join conditions consist of remote-safe expressions.
+ * 3) Join source relations don't have any local filter.
+ */
+static void
+postgresGetForeignJoinPaths(PlannerInfo *root,
+							RelOptInfo *joinrel,
+							RelOptInfo *outerrel,
+							RelOptInfo *innerrel,
+							JoinType jointype,
+							SpecialJoinInfo *sjinfo,
+							SemiAntiJoinFactors *semifactors,
+							List *restrictlist,
+							Relids extra_lateral_rels)
+{
+	ForeignPath	   *joinpath;
+	ForeignPath	   *path_o = (ForeignPath *) outerrel->cheapest_total_path;
+	ForeignPath	   *path_i = (ForeignPath *) innerrel->cheapest_total_path;
+	PgFdwRelationInfo *fpinfo_o;
+	PgFdwRelationInfo *fpinfo_i;
+	PgFdwRelationInfo *fpinfo;
+	double			rows;
+	Cost			startup_cost;
+	Cost			total_cost;
+	ListCell	   *lc;
+	List		   *fdw_private;
+	List		   *joinclauses;
+	List		   *otherclauses;
+
+	/*
+	 * Both outer and inner path should be ForeignPath.
+	 * If either of underlying relations is a SubqueryScan or something,
+	 * RelOptInfo.fdw_handler of such relation is set to InvalidOid to indicate
+	 * that the node can't be handled by FDW.
+	 */
+	Assert(IsA(path_o, ForeignPath) && IsA(path_i, ForeignPath));
+
+	joinclauses = restrictlist;
+	if (IS_OUTER_JOIN(jointype))
+	{
+		extract_actual_join_clauses(joinclauses, &joinclauses, &otherclauses);
+	}
+	else
+	{
+		joinclauses = extract_actual_clauses(joinclauses, false);
+		otherclauses = NIL;
+	}
+
+	/*
+	 * Currently we don't push-down joins in query for UPDATE/DELETE.  This
+	 * restriction might be relaxed in a later release.
+	 */
+	if (root->parse->commandType != CMD_SELECT)
+	{
+		ereport(DEBUG3, (errmsg("command type is not SELECT")));
+		return;
+	}
+
+	/*
+	 * Skip considering reversed combination of inner join.
+	 * Other kinds of join have different meaning when outer and inner are
+	 * reversed.
+	 */
+	if (jointype == JOIN_INNER && outerrel->relid < innerrel->relid)
+	{
+		ereport(DEBUG3, (errmsg("reversed combination of INNER JOIN")));
+		return;
+	}
+
+	/*
+	 * Both relations in the join must belong to same server.
+	 */
+	fpinfo_o = path_o->path.parent->fdw_private;
+	fpinfo_i = path_i->path.parent->fdw_private;
+	if (fpinfo_o->server->serverid != fpinfo_i->server->serverid)
+	{
+		ereport(DEBUG3, (errmsg("server unmatch")));
+		return;
+	}
+
+	/*
+	 * We support all outer joins in addition to inner join.
+	 */
+	if (jointype != JOIN_INNER && jointype != JOIN_LEFT &&
+		jointype != JOIN_RIGHT && jointype != JOIN_FULL)
+	{
+		ereport(DEBUG3, (errmsg("unsupported join type (SEMI, ANTI)")));
+		return;
+	}
+
+	/*
+	 * Note that CROSS JOIN (cartesian product) is transformed to JOIN_INNER
+	 * with empty joinclauses. Pushing down CROSS JOIN produces more result
+	 * than retrieving each tables separately, so we don't push down such joins.
+	 */
+	if (jointype == JOIN_INNER && joinclauses == NIL)
+	{
+		ereport(DEBUG3, (errmsg("unsupported join type (CROSS)")));
+		return;
+	}
+
+	/*
+	 * Neither source relation can have local conditions.  This can be relaxed
+	 * if the join is an inner join and local conditions don't contain volatile
+	 * function/operator, but as of now we leave it as future enhancement.
+	 */
+	if (fpinfo_o->local_conds != NULL || fpinfo_i->local_conds != NULL)
+	{
+		ereport(DEBUG3, (errmsg("join with local filter is not supported")));
+		return;
+	}
+
+	/*
+	 * Join condition must be safe to push down.
+	 */
+	foreach(lc, joinclauses)
+	{
+		Expr *expr = (Expr *) lfirst(lc);
+
+		if (!is_foreign_expr(root, joinrel, expr))
+		{
+			ereport(DEBUG3, (errmsg("one of join conditions is not safe to push-down")));
+			return;
+		}
+	}
+
+	/*
+	 * Other condition evaluated on remote side must be safe to push down.
+	 */
+	foreach(lc, otherclauses)
+	{
+		Expr *expr = (Expr *) lfirst(lc);
+
+		if (!is_foreign_expr(root, joinrel, expr))
+		{
+			ereport(DEBUG3, (errmsg("one of filter conditions is not safe to push-down")));
+			return;
+		}
+	}
+
+	/*
+	 * checkAsUser of source pathes should match.
+	 */
+	if (fpinfo_o->checkAsUser != fpinfo_i->checkAsUser)
+	{
+		ereport(DEBUG3, (errmsg("unmatch checkAsUser")));
+		return;
+	}
+
+	/* Here we know that this join can be pushed-down to remote side. */
+
+	/* Construct fpinfo for the join relation */
+	fpinfo = merge_fpinfo(fpinfo_o, fpinfo_i, jointype);
+	joinrel->fdw_private = fpinfo;
+
+	/* TODO determine cost and rows of the join. */
+	rows = fpinfo->rows;
+	startup_cost = fpinfo->startup_cost;
+	total_cost = fpinfo->total_cost;
+
+	fdw_private = list_make4(path_o,
+							 path_i,
+							 makeInteger(jointype),
+							 joinclauses);
+	fdw_private = lappend(fdw_private, otherclauses);
+
+	/*
+	 * Create a new join path and add it to the joinrel which represents a join
+	 * between foreign tables.
+	 */
+	joinpath = create_foreignscan_path(root,
+									   joinrel,
+									   rows,
+									   startup_cost,
+									   total_cost,
+									   NIL,		/* no pathkeys */
+									   NULL,	/* no required_outer */
+									   fdw_private);
+
+	/* Add generated path into joinrel by add_path(). */
+	add_path(joinrel, (Path *) joinpath);
+
+	/* TODO consider parameterized paths */
+}
+
+/*
  * Create a tuple from the specified row of the PGresult.
  *
  * rel is the local representation of the foreign table, attinmeta is
@@ -2846,12 +3242,12 @@ static HeapTuple
 make_tuple_from_result_row(PGresult *res,
 						   int row,
 						   Relation rel,
+						   TupleDesc tupdesc,
 						   AttInMetadata *attinmeta,
 						   List *retrieved_attrs,
 						   MemoryContext temp_context)
 {
 	HeapTuple	tuple;
-	TupleDesc	tupdesc = RelationGetDescr(rel);
 	Datum	   *values;
 	bool	   *nulls;
 	ItemPointer ctid = NULL;
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 950c6f7..3e0c7fa 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -16,6 +16,7 @@
 #include "foreign/foreign.h"
 #include "lib/stringinfo.h"
 #include "nodes/relation.h"
+#include "nodes/plannodes.h"
 #include "utils/relcache.h"
 
 #include "libpq-fe.h"
@@ -52,12 +53,27 @@ extern void deparseSelectSql(StringInfo buf,
 				 RelOptInfo *baserel,
 				 Bitmapset *attrs_used,
 				 List **retrieved_attrs);
-extern void appendWhereClause(StringInfo buf,
+extern void appendConditions(StringInfo buf,
 				  PlannerInfo *root,
 				  RelOptInfo *baserel,
+				  List *outertlist,
+				  List *innertlist,
 				  List *exprs,
-				  bool is_first,
+				  const char *prefix,
 				  List **params);
+extern void deparseJoinSql(StringInfo sql,
+			   PlannerInfo *root,
+			   RelOptInfo *baserel,
+			   Path *path_o,
+			   Path *path_i,
+			   ForeignScan *plan_o,
+			   ForeignScan *plan_i,
+			   const char *sql_o,
+			   const char *sql_i,
+			   JoinType jointype,
+			   List *joinclauses,
+			   List *otherclauses,
+			   List **retrieved_attrs);
 extern void deparseInsertSql(StringInfo buf, PlannerInfo *root,
 				 Index rtindex, Relation rel,
 				 List *targetAttrs, List *returningList,
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 83e8fa7..db95e4e 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -39,6 +39,18 @@ CREATE TABLE "S 1"."T 2" (
 	c2 text,
 	CONSTRAINT t2_pkey PRIMARY KEY (c1)
 );
+CREATE TABLE "S 1"."T 4" (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text,
+	CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 5" (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c4 text,
+	CONSTRAINT t5_pkey PRIMARY KEY (c1)
+);
 
 INSERT INTO "S 1"."T 1"
 	SELECT id,
@@ -54,9 +66,23 @@ INSERT INTO "S 1"."T 2"
 	SELECT id,
 	       'AAA' || to_char(id, 'FM000')
 	FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 4"
+	SELECT id,
+	       id + 1,
+	       'AAA' || to_char(id, 'FM000')
+	FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 2 != 0;	-- delete for outer join tests
+INSERT INTO "S 1"."T 5"
+	SELECT id,
+	       id + 1,
+	       'AAA' || to_char(id, 'FM000')
+	FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 5" WHERE c1 % 3 != 0;	-- delete for outer join tests
 
 ANALYZE "S 1"."T 1";
 ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 4";
+ANALYZE "S 1"."T 5";
 
 -- ===================================================================
 -- create foreign tables
@@ -87,6 +113,18 @@ CREATE FOREIGN TABLE ft2 (
 ) SERVER loopback;
 ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
 
+CREATE FOREIGN TABLE ft4 (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+
+CREATE FOREIGN TABLE ft5 (
+	c1 int NOT NULL,
+	c2 int NOT NULL,
+	c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 5');
+
 -- ===================================================================
 -- tests for validator
 -- ===================================================================
@@ -158,8 +196,6 @@ EXPLAIN (VERBOSE, COSTS false) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
 SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
 -- aggregate
 SELECT COUNT(*) FROM ft1 t1;
--- join two tables
-SELECT t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
 -- subquery
 SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
 -- subquery+MAX
@@ -216,6 +252,38 @@ SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
 SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
 
 -- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- join two tables
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+-- join three tables
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+SELECT t1.c1, t2.c1, t3.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+-- left outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+-- right outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 RIGHT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t2.c1 OFFSET 10 LIMIT 10;
+SELECT t1.c1, t2.c1 FROM ft4 t1 RIGHT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t2.c1 OFFSET 10 LIMIT 10;
+-- full outer join
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1;
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1;
+-- join at WHERE clause
+EXPLAIN (COSTS false, VERBOSE)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON true WHERE (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON true WHERE (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+
+-- ===================================================================
 -- parameterized queries
 -- ===================================================================
 -- simple join
